Table of Contents
MySQL Cluster is a high-availability, high-redundancy version of
MySQL adapted for the distributed computing environment. It uses the
NDB Cluster
storage engine to enable running
several MySQL servers in a cluster. This storage engine is available
in MySQL 5.0 binary releases and in RPMs compatible
with most modern Linux distributions. (Note that both the
mysql-server
and mysql-max
RPMs must be installed in order to have MySQL Cluster capability.)
The operating systems on which MySQL Cluster is currently available are Linux, Mac OS X, and Solaris. (Some users have reported success with running MySQL Cluster on FreeBSD, although this is not yet officially supported by MySQL AB.) We are working to make Cluster run on all operating systems supported by MySQL, including Windows, and will update this page as new platforms are supported.
This chapter represents a work in progress, and its contents are subject to revision as MySQL Cluster continues to evolve. Additional information regarding MySQL Cluster can be found on the MySQL AB Web site at http://www.mysql.com/products/cluster/.
You may wish to make use of two additional online resources provided by MySQL AB:
the MySQL Cluster mailing list.
the Cluster topic area on the MySQL User Forums.
Answers to some commonly asked questions about Cluster may be found in the Section 16.10, “MySQL Cluster FAQ”. If you are new to MySQL Cluster, you may also find our Developer Zone article How to set up a MySQL Cluster for two servers to be helpful.
MySQL Cluster is a technology which enables clustering of in-memory databases in a share-nothing system. The share-nothing architecture allows the system to work with very inexpensive hardware, and without any specific requirements on hardware or software. It also does not have any single point of failure because each component has its own memory and disk.
MySQL Cluster integrates the standard MySQL server with an
in-memory clustered storage engine called NDB
.
In our documentation, the term NDB
refers to
the part of the setup that is specific to the storage engine,
whereas “MySQL Cluster” refers to the combination of
MySQL and the NDB
storage engine.
A MySQL Cluster consists of a set of computers, each running a number of processes including MySQL servers, data nodes for NDB Cluster, management servers, and (possibly) specialized data access programs. The relationship of these components in a cluster is shown here:
All these programs work together to form a MySQL Cluster. When data is stored in the NDB Cluster storage engine, the tables are stored in the data nodes. Such tables are directly accessible from all other MySQL servers in the cluster. Thus, in a payroll application storing data in a cluster, if one application updates the salary of an employee, all other MySQL servers that query this data can see this change immediately.
The data stored in the data nodes for MySQL Cluster can be mirrored; the cluster can handle failures of individual data nodes with no other impact than that a small number of transactions are aborted due to losing the transaction state. Since transactional applications are expected to handle transaction failure, this should not be a source of problems.
By bringing MySQL Cluster to the Open Source world, MySQL makes clustered data management with high availability, high performance, and scalability available to all who need it.
NDB is an in-memory storage engine offering high-availability and data-persistence features.
The NDB storage engine can be configured with a range of failover and load-balancing options, but it is easiest to start with the storage engine at the cluster level. MySQL Cluster's NDB storage engine contains a complete set of data, dependent only on other data within the cluster itself.
We will now describe how to set up a MySQL Cluster consisting of an NDB storage engine and some MySQL servers.
The cluster portion of MySQL Cluster is currently configured independently of the MySQL servers. In a MySQL Cluster, each part of the cluster is considered to be a node.
Note: In many contexts, the term "node" is used to indicate a computer, but when discussing MySQL Cluster it means a process. There can be any number of nodes on a single computer, for which we use the term cluster host.
There are three types of cluster nodes, and in a minimal MySQL Cluster configuration, there will be at least three nodes, one of each of these types:
The management (MGM
) node: The role of this
type of node is to manage the other nodes within the MySQL
Cluster, such as providing configuration data, starting and
stopping nodes, running backup, and so forth. Because this
node type manages the configuration of the other nodes, a node
of this type should be started first, before any other node.
An MGM node is started with the command
ndb_mgmd.
The data node: This is the type of node that stores the cluster's data. There are as many data nodes as there are replicas, times the number of fragments. For example, with two replicas, each having two fragments, you will need four data nodes. It is not necessary to have more than one replica. A data node is started with the command ndbd.
The SQL node: This is the
node that accesses the cluster data. In the case of MySQL
Cluster, a client node is a traditional MySQL server that uses
the NDB Cluster storage engine. An SQL node is typically
started with the command mysqld
--ndbcluster or simply by using
mysqld with ndbcluster
added to my.cnf
.
Configuration of a cluster involves configuring each individual node in the cluster and setting up individual communication links between nodes. MySQL Cluster is currently designed with the intention that storage nodes are homogenous in terms of processor power, memory space, and bandwidth. In addition, in order to provide a single point of configuration, all configuration data for the cluster as a whole is located in one configuration file.
The management server (MGM node) manages the cluster configuration file and the cluster log. Each node in the cluster retrieves the configuration data from the management server, and so requires a way to determine where the management server resides. When interesting events occur in the data nodes, the nodes transfer information about these events to the management server, which then writes the information to the cluster log.
In addition, there can be any number of cluster client processes or applications. These are of two types:
Standard MySQL clients: These are no different for MySQL Cluster than they are for standard (non-Cluster) MySQL. In other words, MySQL Cluster can be accessed from existing MySQL applications written in PHP, Perl, C, C++, Java, Python, Ruby, and so on.
Management clients: These clients connect to the management server and provide commands for starting and stopping nodes gracefully, starting and stopping message tracing (debug versions only), showing node versions and status, starting and stopping backups, and so on.
This section is a “How-To” in which we describe the basics for how to plan, install, configure, and run a MySQL Cluster. Unlike the example in Section 16.4, “MySQL Cluster Configuration”, the result of following the guidelines and procedures outlined below should be a usable MySQL Cluster which meets minimum requirements for availability and safeguarding of data.
In this section, we will cover hardware and software requirements; networking issues; installation of MySQL Cluster; configuration issues; starting, stopping, and restarting the cluster; loading of a sample database; and performing queries.
Basic Assumptions
This How-To makes the following assumptions:
We are setting up our cluster with 4 nodes, each on a separate host, and each with a fixed network address on a typical Ethernet as shown here:
Node | IP Address |
Management (MGM) node | 192.168.0.10 |
MySQL server (SQL) node | 192.168.0.20 |
Data (NDBD) node "A" | 192.168.0.30 |
Data (NDBD) node "B" | 192.168.0.40 |
This may be made clearer in the following diagram:
Note: In the interest of
simplicity (and reliability), we will use only numeric IP
addresses in this How-To. However, if DNS resolution is
available on your network, then it is possible to use
hostnames in lieu of IP addresses in configuring Cluster.
Alternatively, you can also use the
/etc/hosts
file or your operating
system's equivalent for providing a means to do host lookup if
such is available.
Each host in our scenario is an Intel-based desktop PC running a common, generic Linux distribution installed to disk in a standard configuration, and running no unnecessary services. The core OS with a standard TCP/IP networking client should be sufficient. Also for the sake of simplicity, we also assume that the filesystems on all hosts are set up identically. In the event that they are not, you will need to adapt these instructions accordingly.
Standard 100 Mbps or 1 gigabit Ethernet cards are installed on each machine, along with the proper drivers for the cards, and that all 4 hosts are connected via a standard-issue Ethernet networking applicance such as a switch. (All machines should use network cards with the same throughout; that is, all 4 machines in the cluster should have 100 Mbps cards or all 4 machines should have 1 Gbps cards.) MySQL Cluster will work in a 100 Mbps network; however, gigabit Ethernet will provide better performance.
Note that MySQL Cluster is not intended for use in a network whose connectivity is less than 100 Mbps. For this reason (among others), attempting to run a MySQL Cluster over a public network such as the Internet is not likely to be successful, and is not recommended.
For our sample data, we will use the world
database which is available for download from the MySQL AB
website. As this database takes up a relatively small amount
of space, we assume that each machine has 256 MB RAM, which
should be sufficient for running the operating system, host
NDB process, and (for the data nodes) for storing the
database.
While we refer to a Linux operating system in this How-To, the instructions and procedures that we provide here should be easily adaptable to either Solaris or Mac OS X. We also assume that you already know how to perform a minimal installation and configuration of the operating system with networking capability, or that you are able to obtain assistance in this elsewhere if needed.
We discuss MySQL Cluster hardware, software, and networking requirements in somewhat greater detail in the next section. (See Section 16.3.1, “Hardware, Software, and Networking”.)
One of the strengths of MySQL Cluster is that it can be run on commodity hardware and has no ususual requirements in this regard, other than for large amounts of RAM, due to the fact that all live data storage is done in memory. (Note that this is subject to change, and that we intend to implement disk-based storage in a future MySQL Cluster release.) Naturally, multiple and faster CPUs will enhance performance. Memory requirements for Cluster processes are relatively small.
The software requirements for Cluster are also modest. Host
operating systems do not require any unusual modules, services,
applications, or configuration to support MySQL Cluster. For Mac
OS X or Solaris, the standard installation is sufficient. For
Linux, a standard, “out of the box” installation
should be all that is necessary. The MySQL software requirements
are simple: all that is needed is a production release of
MySQL-max 5.0; you must use the
-max
version of MySQL in order to have
Cluster support. It is not necessary to compile MySQL yourself
merely to be able to use Cluster. In this How-To, we assume that
you are using the -max
binary appropriate to
your Linux. Solaris, or Mac OS X operating system, available via
the MySQL software downloads page at
http://dev.mysql.com/downloads.
For inter-node communication, Cluster supports TCP/IP networking in any standard topology, and the minimum expected for each host is a standard 100 Mbps Ethernet card, plus a switch, hub, or router to provide network connectivity for the cluster as a whole. We strongly recommend that a MySQL Cluster be run on its own subnet which is not shared with non-Cluster machines for the following reasons:
Security: Communications between Cluster nodes are not encrypted or shielded in any way. The only means of protecting transmissions within a MySQL Cluster is to run your Cluster on a protected network. If you intend to use MySQL Cluster for Web applications, the cluster should definitely reside behind your firewall and not in your network's De-Militarised Zone (DMZ) or elsewhere.
Efficiency: Setting up a MySQL Cluster on a private or protected network allows for the cluster to make exclusive use of bandwidth between cluster hosts. Using a separate switch for your MySQL Cluster not only helps protect against unauthorised access to Cluster data, it also ensures that Cluster nodes are shielded from interference caused by transmissions between other computers on the network. For enhanced reliability, you can use dual switches and dual cards to remove the network as a single point of failure; many device drivers support failover for such communication links.
It is also possible to use the high-speed Scalable Coherent Interface (SCI) with MySQL Cluster, but this is not a requirement. See Section 16.7, “Using High-Speed Interconnects with MySQL Cluster” for more about this protocol and its use with MySQL Cluster.
Each MySQL Cluster host computer running storage or SQL nodes must have installed on it a MySQL-max binary. For management nodes, it is not necessary to install the MySQL server binary, but you do have to install the MGM server daemon and client binaries (ndb_mgmd and ndb_mgm, respectively). In this section, we will cover the steps necessary to install the correct binaries for each type of Cluster node.
MySQL AB provides precompiled binaries which support Cluster,
and there is generally no need to compile these yourself. (If
you do require a custom binary, see
Section 2.8.3, “Installing from the Development Source Tree”.) Therefore, the first
step in the installation process for each cluster host is to
download the file
mysql-max-5.0.15-pc-linux-gnu-i686.tar.gz
from the MySQL
downloads area. We assume that you have placed it in
each machine's /var/tmp
directory.
RPMs are also available for both 32-bit and 64-bit Linux
platforms; the -max
binaries installed by the
RPMs support the NDBCluster
storage engine.
If you choose to use these rather than the binary files, be
aware that you must install both the
-server
and -max
packages
on all machines that are to host cluster nodes. (See
Section 2.4, “Installing MySQL on Linux” for more information about
installing MySQL using the RPMs.) After installing from RPM, you
will still need to configure the cluster as discussed in
Section 16.3.3, “Configuration”.
Note: After completing the installation, do not yet start any of the binaries. We will show you how to do so following the configuration of all nodes.
Storage and SQL Node Installation
On each of the 3 machines designated to host storage or SQL nodes, perform the following steps as the system root user:
Check your /etc/passwd
and
/etc/group
files (or use whatever tools
are provided by your operating system for manging users and
groups) to see whether or not there are already a
mysql
group and mysql
user on the system, as some OS distributions create these as
part of the operating system installation process. If these
are not already present, then create a new
mysql
user group, then add a
mysql
user to this group:
groupadd mysql useradd -g mysql mysql
Change to the directory containing the downloaded file; unpack the archive; create a symlink to the mysql-max executable. Note that the actual file and directory names will vary according to the MySQL version number.
cd /var/tmp tar -xzvf -C /usr/local/bin mysql-max-5.0.15-pc-linux-gnu-i686.tar.gz ln -s /usr/local/bin/mysql-max-5.0.15-pc-linux-gnu-i686 mysql
Change to the mysql
directory, and run
the supplied script for creating the system databases:
cd mysql scripts/mysql_install_db --user=mysql
Set the necessary permissions for the MySQL server and data directories:
chown -R root . chown -R mysql data chgrp -R mysql .
Note that the data directory on each machine hosting a data
node is /usr/local/mysql/data
. We will
make use of this piece of information when we configure the
management node. (See Section 16.3.3, “Configuration”.)
Copy the MySQL startup script to the appropriate directory, make it executable, and set it to start when the operating system is booted up:
cp support-files/mysql.server /etc/rc.d/init.d/ chmod +x /etc/rc.d/init.d/mysql.server chkconfig --add mysql.server
Here we use Red Hat's chkconfig for creating links to the startup scripts; use whatever means is appropriate for this purpose on your operating system/distribution, such as update-rc.d on Debian.
Remember that the steps listed above must be performed separately for each machine on which a storage or SQL node is to reside.
Management Node Installation
For the MGM (management) node, it is not necessary to install
the mysqld executable, only the binaries for
the MGM server and client, which can be found in the downloaded
-max
archive. Again we assume that you have
placed this file in /var/tmp
. As system
root (that is, after using sudo, su
root, or your system's equivalent for temporarily
assuming the system administrator account's privileges), perform
the following steps to install ndb_mgmd and
ndb_mgm on the Cluster management node host:
Move to the /var/tmp
directory, and
extract the ndb_mgm and
ndb_mgmd from the archive into a suitable
directory such as /usr/local/bin
:
cd /var/tmp tar -zxvf mysql-max-5.0.15-pc-linux-gnu-i686.tar.gz /usr/local/bin '*/bin/ndb_mgm*'
Move to the directory into which you unpacked the files, and then make both of these executable:
cd /usr/local/bin chmod +x ndb_mgm*
In Section 16.3.3, “Configuration”, we will create and write configuration files for all of the nodes in our example Cluster.
For our 4-node, 4-host MySQL Cluster, we will need to write 4 configuration files, 1 per node/host.
Each data node or SQL node will require a
my.cnf
file that provides two pieces of
information: a
connectstring telling the
node where to find the MGM node, and a line telling the
MySQL server on this host (the machine hosting the data
node) to run in NDB mode.
For more information on connectstrings, see
Section 16.4.4.2, “The MySQL Cluster connectstring
”.
The management node will need a
config.ini
file telling it how many
replicas are to be maintained, how much memory to allocate
for data and indexes on each data node, where to find the
data nodes, where data will be saved to disk on each data
node, and where to find any SQL nodes.
Configuring the Storage and SQL Nodes
The my.cnf
file needed for the data nodes
is fairly simple. The configuration file should be located in
the /etc
directory and can be edited (and
created if necessary) using any text editor, for example:
vi /etc/my.cnf
For each data node and SQL node in our example setup,
my.cnf
should look like this:
# Options for mysqld process: [MYSQLD] ndbcluster # run NDB engine ndb-connectstring=192.168.0.10 # location of MGM node # Options for ndbd process: [MYSQL_CLUSTER] ndb-connectstring=192.168.0.10 # location of MGM node
After entering the above, save this file and exit the text editor. Do this for the machines hosting data node "A", data node "B", and the SQL node.
Configuring the Management Node
The first step in configuring the MGM node is to create the directory in which the configuration file can be found and then to create the file itself. For example (running as root):
mkdir /var/lib/mysql-cluster cd /var/lib/mysql-cluster vi config.ini
We show vi being used here to create the file, but any text editor should work just as well.
For our representative setup, the
config.ini
file should read as follows:
# Options affecting ndbd processes on all data nodes: [NDBD DEFAULT] NoOfReplicas=2 # Number of replicas DataMemory=80M # How much memory to allocate for data storage IndexMemory=18M # How much memory to allocate for index storage # For DataMemory and IndexMemory, we have used the # default values. Since the "world" database takes up # only about 500KB, this should be more than enough for # this example Cluster setup. # TCP/IP options: [TCP DEFAULT] portnumber=2202 # This the default; however, you can use any # port that is free for all the hosts in cluster # Note: It is recommended beginning with MySQL 5.0 that # you do not specify the portnumber at all and simply allow # the default value to be used instead # Management process options: [NDB_MGMD] hostname=192.168.0.10 # Hostname or IP address of MGM node datadir=/var/lib/mysql-cluster # Directory for MGM node logfiles # Options for data node "A": [NDBD] # (one [NDBD] section per data node) hostname=192.168.0.30 # Hostname or IP address datadir=/usr/local/mysql/data # Directory for this data node's datafiles # Options for data node "B": [NDBD] hostname=192.168.0.40 # Hostname or IP address datadir=/usr/local/mysql/data # Directory for this data node's datafiles # SQL node options: [MYSQLD] hostname=192.168.0.20 # Hostname or IP address # (additional mysqld connections can be # specified for this node for various # purposes such as running ndb_restore)
(NOTE: The "world" database can be downloaded from http://dev.mysql.com/doc/ where it can be found listed under "Examples".)
Once all the configuration files have been created and these minimal options have been specified, you are ready to proceed with starting the cluster and verifying that all processes are running. We discuss how this is done in Section 16.3.4, “Initial Startup”.
For more detailed information about the available MySQL Cluster configuration parameters and their uses, see Section 16.4.4, “Configuration File” and Section 16.4, “MySQL Cluster Configuration”. For configuration of MySQL Cluster as relates to making backups, see Section 16.6.5.4, “Configuration for Cluster Backup”.
Note: The default port for Cluster management nodes is 1186; the default port for data nodes is 2202. Beginning with MySQL 5.0.3, this restriction is lifted, and the cluster will automatically allocate ports for data nodes from those that are already free.
Starting the cluster is not very difficult once it has been configured. Each cluster node process must be started separately, and on the host where it resides. While it is possible to start the nodes in any order, it is recommended that the management node be started first, followed by the storage nodes, and then finally by any SQL nodes:
On the management host, issue the following command from the system shell to start the MGM node process:
shell> ndb_mgmd -f /var/lib/mysql-cluster/config.ini
Note that ndb_mgmd must be told where to
find its configuration file, using the -f
or --config-file
option. (See
Section 16.5.3, “ndb_mgmd, the Management Server Process” for details.)
On each of the data node hosts, run this command to start the NDBD process for the first time:
shell> ndbd --initial
Note that it is very important to use the
--initial
parameter
only when starting
ndbd for the first time, or when
restarting after backup/restore or configuration change.
This is because this parameter will cause the node to delete
any files created by earlier ndbd
instances needed for recovery, including the recovery log
files.
If you have used the RPMs to install MySQL on the cluster
host where the SQL node is to reside, you can (and should)
use the startup script installed to
/etc/init.d
to start the MySQL server
process on the SQL node. Note that you need to install the
-max
server RPM in addition
to the Standard server RPM in order to run the
-max
server binary.
If all has gone well, and the cluster has been set up correctly, the cluster should now be operational. You can test this by invoking the ndb_mgm management node client; the output should look like what is shown below:
shell> ndb_mgm
-- NDB Cluster -- Management Client --
ndb_mgm> SHOW
Connected to Management Server at: localhost:1186
Cluster Configuration
---------------------
[ndbd(NDB)] 2 node(s)
id=2 @192.168.0.30 (Version: 5.0.15, Nodegroup: 0, Master)
id=3 @192.168.0.40 (Version: 5.0.15, Nodegroup: 0)
[ndb_mgmd(MGM)] 1 node(s)
id=1 @192.168.0.10 (Version: 5.0.15)
[mysqld(SQL)] 1 node(s)
id=4 (Version: 5.0.15)
You may see some slight differences in the output depending upon the exact version of MySQL that you are using.
Note: If you are using an older
version of MySQL, you may see the SQL node referenced as
‘[mysqld(API)]
’. This reflects an
older usage which is now deprecated.
You should now be ready to work with databases, tables, and data in MySQL Cluster. See Section 16.3.5, “Loading Sample Data and Performing Queries” for a brief discussion.
Working with data in MySQL Cluster is not much different than working with it MySQL without Cluster. There are two points to keep in mind when doing so:
Tables must be created with the ENGINE=NDB
or ENGINE=NDBCLUSTER
option, or be altered
(using ALTER TABLE
) to use the NDB
CLuster storage engine in order to have them replicated in
the cluster. If you are importing tables from an existing
database using the output of mysqldump,
you can open the SQL script(s) in a text editor and add this
option to any table creation statements, or replace any
existing ENGINE
(or
TYPE
) option(s) with one of these. For
example, suppose that you have the sample
world
database on another MySQL server
(that does not support MySQL Cluster), and you wish to
export the definition for the City
table:
shell> mysqldump --add-drop-table world City > city_table.sql
The resulting city_table.sql
file will
contain this table creation statement (and the
INSERT
statements necessary to import the
table data):
DROP TABLE IF EXISTS City; CREATE TABLE City ( ID int(11) NOT NULL auto_increment, Name char(35) NOT NULL default '', CountryCode char(3) NOT NULL default '', District char(20) NOT NULL default '', Population int(11) NOT NULL default '0', PRIMARY KEY (ID) ) ENGINE=MyISAM; INSERT INTO City VALUES (1,'Kabul','AFG','Kabol',1780000); INSERT INTO City VALUES (2,'Qandahar','AFG','Qandahar',237500); INSERT INTO City VALUES (3,'Herat','AFG','Herat',186800); # (remaining INSERT statements omitted)
You will need to make sure that MySQL uses the NDB storage
engine for this table. There are two ways that this can be
accomplished. One of these is, before
importing the table into the Cluster database, to modify its
definition so that it reads (still using
City
as an example):
DROP TABLE IF EXISTS City; CREATE TABLE City ( ID int(11) NOT NULL auto_increment, Name char(35) NOT NULL default '', CountryCode char(3) NOT NULL default '', District char(20) NOT NULL default '', Population int(11) NOT NULL default '0', PRIMARY KEY (ID) ) ENGINE=NDBCLUSTER; INSERT INTO City VALUES (1,'Kabul','AFG','Kabol',1780000); INSERT INTO City VALUES (2,'Qandahar','AFG','Qandahar',237500); INSERT INTO City VALUES (3,'Herat','AFG','Herat',186800); # (etc.)
This will need to be done for the definition of each table
that is to be part of the clustered database. The easiest
way to accomplish this is simply to do a search-and-replace
on the world.sql
file and replace all
instances of TYPE=MyISAM
with
ENGINE=NDBCLUSTER
. If you do not wish to
modify the file, you can also use ALTER
TABLE
; see below for particulars.
Assuming that you have already created a database named
world
on the SQL node of the cluster, you
can then use the mysql command-line
client to read city_table.sql
, and
create and populate the corresponding table in the usual
manner:
shell> mysql world < city_table.sql
It is very important to keep in mind that the above command must be executed on the host where the SQL node is running -- in this case, on the machine with the IP address 192.168.0.20.
To create a copy of the world
database on
the SQL node, save the file to
/usr/local/mysql/data
, then run
shell>cd /usr/local/mysql/data
shell>mysql world < world.sql
Of course, the SQL script must be readable by the
mysql
system user. If you save the file
to a different location, adjust the above accordingly.
It is important to note that NDB Cluster
in MySQL 5.0 does not support autodiscovery of
databases. (See
Section 16.8, “Known Limitations of MySQL Cluster”.) This means
that, once the world
database and its
tables have been created on one data node, you need to issue
the command CREATE DATABASE world;
(beginning with MySQL 5.0.2, you may use CREATE
SCHEMA world; instead), followed by FLUSH
TABLES; on each SQL node in the cluster. This will
cause the node to recognise the database and read its table
definitions.
Running SELECT queries on the SQL node is no different than running them on any other instance of a MySQL server. To run queries from the command line, you first need to log in to the MySQL Monitor in the usual way:
shell>mysql -u root -p
Enter password: Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 1 to server version: 5.0.15 Type 'help;' or '\h' for help. Type '\c' to clear the buffer. mysql>
If you did not modify the ENGINE=
clauses
in the table definitions prior to importing the SQL script,
then you should at this point run the following commands:
mysql>USE world;
mysql>ALTER TABLE City ENGINE=NDBCLUSTER;
mysql>ALTER TABLE Country ENGINE=NDBCLUSTER;
mysql>ALTER TABLE CountryLanguage ENGINE=NDBCLUSTER;
Note that we simply use the MySQL server's default
root
account with its empty password
here. Of course, in a production setting, you should
always follow the standard security
precautions for installing a MySQL server, including the
setting of a strong root password and creation of a user
account with only those privileges required to accomplish
the tasks necessary for that user. For more information
about these, see Section 5.7, “The MySQL Access Privilege System”.
It is worth taking into account that Cluster nodes do not
make use of the MySQL privileges system when accessing one
another, and setting or changing MySQL user accounts
(including the root
account) has no
effect on interaction between nodes, only on applications
accessing the SQL node.
Selecting a database and running a SELECT query against a table in that database is also accomplished in the usual manner, as is exiting the MySQL Monitor:
mysql>USE world;
mysql>SELECT Name, Population FROM City ORDER BY Population DESC LIMIT 5;
+-----------+------------+ | Name | Population | +-----------+------------+ | Bombay | 10500000 | | Seoul | 9981619 | | São Paulo | 9968485 | | Shanghai | 9696300 | | Jakarta | 9604900 | +-----------+------------+ 5 rows in set (0.34 sec) mysql>\q
Bye shell>
Applications using MySQL can use standard APIs. It is
important to remember that your application must access the
SQL node, and not the MGM or storage nodes. This brief
example shows how we might execute the same query as above
using PHP 5's mysqli
extension running on
a Web server elsewhere on the network:
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd"> <html> <head> <meta http-equiv="Content-Type" content="text/html; charset=iso-8859-1"> <title>SIMPLE mysqli SELECT</title> </head> <body> <?php # connect to SQL node: $link = new mysqli('192.168.0.20', 'root', '', 'world'); # parameters for mysqli constructor are: # host, user, password, database if( mysqli_connect_errno() ) die("Connect failed: " . mysqli_connect_error()); $query = "SELECT Name, Population FROM City ORDER BY Population DESC LIMIT 5"; # if no errors... if( $result = $link->query($query) ) { ?> <table border="1" width="40%" cellpadding="4" cellspacing ="1"> <tbody> <tr> <th width="10%">City</th> <th>Population</th> </tr> <? # then display the results... while($row = $result->fetch_object()) printf(<tr>\n <td align=\"center\">%s</td><td>%d</td>\n</tr>\n", $row->Name, $row->Population); ?> </tbody </table> <? # ...and verify the number of rows that were retrieved printf("<p>Affected rows: %d</p>\n", $link->affected_rows); } else # otherwise, tell us what went wrong echo mysqli_error(); # free the result set and the mysqli connection object $result->close(); $link->close(); ?> </body> </html>
We assume that the process running on the Web server can reach the IP address of the SQL node.
In a similar fashion, you can use the MySQL C API, Perl-DBI, Python-mysql, or MySQL AB's own Connectors to perform the tasks of data definition and manipulation just as you would normally with MySQL.
Also remember that each NDB
table must have a primary key. If no primary key
is defined by the user when a table is created, the
NDB Cluster
storage engine will
automatically generate a hidden one.
(Note: This hidden key
takes up space just as does any other table index. It is not
uncommon to encounter problems due to insufficient memory
for accommodating these automatically created keys.)
To shut down the cluster simply enter the following in a shell on the machine hosting the MGM node:
shell> ndb_mgm -e shutdown
This will cause the ndb_mgm,
ndb_mgmd, and any ndbd
processes to terminate gracefully. Any SQL nodes can be
terminated using mysqladmin shutdown and
other means. Note that the -e
option here is
used to pass a command to the ndb_mgm client
from the shell. See Section 4.3.1, “Using Options on the Command Line”.
To restart the cluster, simply run these commands:
On the management host (192.168.0.10
in
our setup):
shell> ndb_mgmd -f /var/lib/mysql-cluster/config.ini
On each of the data node hosts
(192.168.0.30
and
192.168.0.40
):
shell> ndbd
Remember not to invoke this
command with the --initial
option when
restarting an NDBD node normally.
And on the SQL host (192.168.0.20
):
shell> mysqld &
For information on making Cluster backups, see Section 16.6.5.2, “Using The Management Server to Create a Backup”.
To restore the cluster from backup requires the use of the ndb_restore command. This is covered in Section 16.6.5.3, “How to Restore a Cluster Backup”.
More information on configuring MySQL Cluster can be found in Section 16.4, “MySQL Cluster Configuration”.
A MySQL server that is part of a MySQL Cluster differs in only one
respect from a normal (non-clustered) MySQL server, in that it
employs the NDB Cluster
storage engine. This
engine is also referred to simply as NDB
, and
the two forms of the name are synonomous.
In order to avoid unnecessary allocation of resources, the server
is configured by default with the NDB
storage
engine disabled. To enable NDB
, you will need
to modify the server's my.cnf
configuration
file, or start the server with the --ndbcluster
option.
Since the MySQL server is a part of the cluster, it will also need
to know how to access an MGM node in order to obtain the cluster
configuration data. The default behavior is to look for the MGM
node on localhost
. However, should you need to
specify its location elsewhere, this can be done in
my.cnf
or on the MySQL server command line.
Before the NDB
storage engine can be used, at
least one MGM node must be operational, as well as any desired
data nodes.
NDB
, the Cluster storage engine, is available
in binary distributions for Linux, Mac OS X, and Solaris. It is
not yet supported on Windows, but we intend to make it available
for win32 and other platforms in the near future.
If you choose to build from a source tarball or the MySQL
5.0 BitKeeper tree, be sure to use the
--with-ndbcluster
option when running
configure. You can also use the
BUILD/compile-pentium-max build script. Note
that this script includes OpenSSL, so you must have or obtain
OpenSSL to build successfully; otherwise you will need to modify
compile-pentium-max to exclude this
requirement. Of course, you can also just follow the standard
instructions for compiling your own binaries, then perform the
usual tests and installation procedure. See
Section 2.8.3, “Installing from the Development Source Tree”.
In the next few sections, we assume that you are already familiar with installing MySQL, and here we cover only the differences between configuring MySQL Cluster and configuring MySQL without clustering. (See Chapter 2, Installing MySQL if you require more information about the latter.)
You will find Cluster configuration easiest if you have already
have all management and data nodes running first; this is likely
to be the most time-consuming part of the configuration. Editing
the my.cnf
file is fairly straightforward,
and this section will cover only any differences from
configuring MySQL without clustering.
In order to familiarise you with the basics, we will describe the simplest possible configuration for a functional MySQL Cluster. After this, you should be able to design your desired setup from the information provided in the other relevant sections of this chapter.
First, you need to create a configuration directory such as
/var/lib/mysql-cluster
, by executing the
following command as the system root user:
shell> mkdir /var/lib/mysql-cluster
In this directory, create a file named
config.ini
with the following information,
substituting appropriate values for HostName
and DataDir
as necessary for your system.
# file "config.ini" - showing minimal setup consisting of 1 data node, # 1 management server, and 3 MySQL servers. # The empty default sections are not required, and are shown only for # the sake of completeness. # Data nodes must provide a hostname but MySQL Servers are not required # to do so. # If you don't know the hostname for your machine, use localhost. # The DataDir parameter also has a default value, but it is recommended to # set it explicitly. # Note: DB, API, and MGM are aliases for NDBD, MYSQLD, and NDB_MGMD # respectively. DB and API are deprecated and should not be used in new # installations. [NDBD DEFAULT] NoOfReplicas= 1 [MYSQLD DEFAULT] [NDB_MGMD DEFAULT] [TCP DEFAULT] [NDB_MGMD] HostName= myhost.example.com [NDBD] HostName= myhost.example.com DataDir= /var/lib/mysql-cluster [MYSQLD] [MYSQLD] [MYSQLD]
You can now start the management server as follows:
shell>cd /var/lib/mysql-cluster
shell>ndb_mgmd
Then start a single DB node by running ndbd.
When starting ndbd for a given DB node for
the very first time, you should use the
--initial
option as shown here:
shell> ndbd --initial
For subsequent ndbd starts, you will generally not want to use this option:
shell> ndbd
This is because the --initial
option will
delete all existing data and log files (as well as all table
metadata) for this data node and create new ones. One exception
to this rule is when restarting the cluster and restoring from
backup after adding new data nodes.
By default, ndbd will look for the management
server at localhost
on port 1186.
Note: If you have installed
MySQL from a binary tarball, you will need to specify the path
of the ndb_mgmd and ndbd
servers explicitly. (Normally, these will be found in
/usr/local/mysql/bin
.)
Finally, go to the MySQL data directory (usually
/var/lib/mysql
or
/usr/local/mysql/data
), and make sure that
the my.cnf
file contains the option
necessary to enable the NDB storage engine:
[mysqld] ndbcluster
You can now start the MySQL server as usual:
shell> mysqld_safe --user=mysql &
Wait a moment to make sure the MySQL server is running properly.
If you see the notice mysql ended
, check the
server's .err
file to find out what went
wrong.
If all has gone well so far, you now can start using the cluster:
shell>mysql
Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 1 to server version: 5.0.15-Max Type 'help;' or '\h' for help. Type '\c' to clear the buffer. mysql>SHOW ENGINES\G
... *************************** 12. row *************************** Engine: NDBCLUSTER Support: YES Comment: Clustered, fault-tolerant, memory-based tables *************************** 13. row *************************** Engine: NDB Support: YES Comment: Alias for NDBCLUSTER ...
(Note that the row numbers shown in the example output above may be different from those shown on your system, depending upon the MySQL version being used and how it is configured.)
shell>mysql
Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 1 to server version: 5.0.15-Max Type 'help;' or '\h' for help. Type '\c' to clear the buffer. mysql>USE test;
Database changed mysql>CREATE TABLE ctest (i INT) ENGINE=NDBCLUSTER;
Query OK, 0 rows affected (0.09 sec) mysql>SHOW CREATE TABLE ctest \G
*************************** 1. row *************************** Table: ctest Create Table: CREATE TABLE `ctest` ( `i` int(11) default NULL ) ENGINE=ndbcluster DEFAULT CHARSET=latin1 1 row in set (0.00 sec)
To check that your nodes were set up properly, start the management client as shown:
shell> ndb_mgm
You can then use the SHOW command from within the management client in order to obtain a report on the cluster's status:
NDB> SHOW Cluster Configuration --------------------- [ndbd(NDB)] 1 node(s) id=2 @127.0.0.1 (Version: 3.5.3, Nodegroup: 0, Master) [ndb_mgmd(MGM)] 1 node(s) id=1 @127.0.0.1 (Version: 3.5.3) [mysqld(API)] 3 node(s) id=3 @127.0.0.1 (Version: 3.5.3) id=4 (not connected, accepting connect from any host) id=5 (not connected, accepting connect from any host)
At this point, you have successfully set up a working MySQL
Cluster. You can now store data in the cluster by using any
table created with ENGINE=NDBCLUSTER
or its
alias ENGINE=NDB
.
connectstring
Configuring MySQL Cluster requires working with two files:
my.cnf
: Specifies options for all MySQL
Cluster executables. This file, with which you should be
familiar with from previous work with MySQL, must be
accessible by each executable running in the cluster.
config.ini
: This file is read only by
the MySQL Cluster management server, which then distributes
the information contained in this file to all processes
participating in the cluster.
config.ini
contains a description of
each node involved in the cluster. This includes
configuration parameters for data nodes and configuration
parameters for connections between all nodes in the cluster.
We are continuously making improvements in Cluster configuration and attempting to simplify this process. While we strive to maintain backwards compatibility, there may be times when introduce an incompatible change. In such cases we will try to let Cluster users know in advance if a change is not backwards compatible. If you find such a change which we have not documented, please use our Bugs Database to report it.
In order to support MySQL Cluster, you will need to update
my.cnf
as shown in the example below.
Note that the options shown here should not be confused with
those occurring in config.ini
files. You
may also specify these parameters when invoking the
executables from the command line.
# my.cnf # example additions to my.cnf for MySQL Cluster # (valid in MySQL 5.0) # enable ndbcluster storage engine, and provide connectstring for # management server host (default port is 1186) [mysqld] ndbcluster ndb-connectstring=ndb_mgmd.mysql.com # provide connectstring for management server host (default port: 1186) [ndbd] connect-string=ndb_mgmd.mysql.com # provide connectstring for management server host (default port: 1186) [ndb_mgm] connect-string=ndb_mgmd.mysql.com # provide location of cluster configuration file [ndb_mgmd] config-file=/etc/config.ini
(For more information on connectstrings, see
Section 16.4.4.2, “The MySQL Cluster connectstring
”.)
# my.cnf # example additions to my.cnf for MySQL Cluster # (will work on all versions) # enable ndbcluster storage engine, and provide connectstring for management # server host to the default port 1186 [mysqld] ndbcluster ndb-connectstring=ndb_mgmd.mysql.com:1186
You may also use a separate [mysql_cluster]
section in the cluster my.cnf
for
settings to be read by and affecting all executables:
# cluster-specific settings [mysql_cluster] ndb-connectstring=ndb_mgmd.mysql.com:1186
Currently the configuration file is in INI format, and is
named config.ini
by default. It is read
by ndb_mgmd at startup and can be placed
anywhere. Its location and name are specified by using
--config-file=[
on the command line with ndb_mgmd. If the
configuration file is not specified,
ndb_mgmd by default tries to read a
<path>
]<filename>
config.ini
file located in the current
working directory.
Default values are defined for most parameters, and can also
be specified in config.ini
. To create a
default value section, simply add the word
DEFAULT
to the section name. For example,
data nodes are configured using [NDBD]
sections. If all data nodes use the same data memory size, and
this is not the same as the default size, create an
[NDBD DEFAULT]
section containing a
DataMemory
line to specify the default data
memory size for all data nodes.
The INI format consists of sections preceded by section
headings (surrounded by square brackets), followed by the
appropriate parameter names and values. One deviation from the
standard format is that the parameter name and value can be
separated by a colon (‘:
’) as
well as the equals sign (‘=
’);
another is that sections are not uniquely identified by name.
Instead, unique entries (such as two different nodes of the
same type) are identified by a unique ID.
At a minimum, the configuration file must define the computers and nodes involved in the cluster and on which computers these nodes are located. An example of a simple configuration file for a cluster consisting of one management server, two data nodes and two MySQL servers is shown below:
# file "config.ini" - 2 data nodes and 2 SQL nodes # This file is placed in the startup directory of ndb_mgmd (the management # server) # The first MySQL Server can be started from any host. The second can be started # only on the host mysqld_5.mysql.com [NDBD DEFAULT] NoOfReplicas= 2 DataDir= /var/lib/mysql-cluster [NDB_MGMD] Hostname= ndb_mgmd.mysql.com DataDir= /var/lib/mysql-cluster [NDBD] HostName= ndbd_2.mysql.com [NDBD] HostName= ndbd_3.mysql.com [MYSQLD] [MYSQLD] HostName= mysqld_5.mysql.com
There are six different sections in this configuration file:
[COMPUTER]
: Defines the the cluster
hosts.
[NDBD]
: Defines the cluster's data
nodes.
[MYSQLD]
: Defines the cluster's MySQL
server nodes.
[MGM]
or [NDB_MGMD]
:
Defines the cluster's management server node.
[TCP]
: Defines TCP/IP connections
between nodes in the cluster, with TCP/IP being the
default connection protocol.
[SHM]
: Defines shared-memory
connections between nodes. Formerly, this type of
connection was available only in binaries that were built
using the --with-ndb-shm
option. In MySQL
5.0-Max, it is enabled by default, but should
still be considered experimental.
Note that each node has its own section in the
config.ini
. For instance, since this
cluster has two data nodes, the configuration file contains
two sections defining these nodes.
You can define DEFAULT
values for each
section. In MySQL 5.0, all parameter names are
case-insensitive.
With the exception of the MySQL Cluster management server (ndb_mgmd), each node making up a MySQL Cluster requires a connectstring which points to the management server's location. This is used in establishing a connection to the management server as well as in performing other tasks depending on the node's role in the cluster. The syntax for a connectstring is as follows:
<connectstring> := [<nodeid-specification>,]<host-specification>[,<host-specification>] <nodeid-specification> :=node_id
<host-specification> :=host
[:port
]
node_id
is an integer larger than 1 which
identifies a node in config.ini
.
port
is an integer referring to a
regular Unix port. host
is a string
representing a valid Internet host address.
example 1 (long): "nodeid=2,myhost1:1100,myhost2:1100,192.168.0.3:1200" example 2 (short): "myhost1"
All nodes will use localhost:1186
as the
default connectstring value if none is provided. If
<port>
is omitted from the
connectstring, the default port is 1186. This port should
always be available on the network, since it has been assigned
by IANA for this purpose (see
http://www.iana.org/assignments/port-numbers
for details).
By listing multiple
<host-specification>
values, it is
possible to designate several redundant management servers. A
cluster node will attempt to contact successive management
servers on each host in the order specified, until a
successful connection has been established.
There are a number of different ways to specify the connectstring:
Each executable has its own command line option which enables specifying the management server at startup. (See the documentation for the respective executable.)
It is also possible in MySQL 5.0 Cluster to
set the connectstring for all nodes in the cluster at once
by placing it in a [mysql_cluster]
section in the management server's
my.cnf
file.
For backwards compatibility, two other options are available, using the same syntax:
Set the NDB_CONNECTSTRING
environment
variable to contain the connectstring.
Write the connectstring for each executable into a
text file named Ndb.cfg
and place
this file in the executable's startup directory.
However, these are now deprecated and should not be used for new installations.
The recommended method for specifying the connectstring is to
set it on the command line or in the
my.cnf
file for each executable.
The [COMPUTER]
section has no real
significance other than serving as a way to avoid the need of
defining host names for each node in the system. All
parameters mentioned here are required.
[COMPUTER]Id
This is an integer value, used to refer to the host computer elsewhere in the configuration file.
[COMPUTER]HostName
This is the computer's hostname or IP address.
The [NDB_MGMD]
section (or its alias
[MGM]
) is used to configure the behavior of
the management server. All parameters in the following list
can be omitted and, if so, will assume their default values.
Note: If neither the
ExecuteOnComputer
nor the
HostName
parameter is present, the default
value localhost
will be assumed for both.
[NDB_MGMD]Id
Each node in the cluster has a unique identity, which is represented by an integer value in the range 1 to 63 inclusive. This ID is used by all internal cluster messages for addressing the node.
[NDB_MGMD]ExecuteOnComputer
This refers to one of the computers defined in the
[COMPUTER]
section.
[NDB_MGMD]PortNumber
This is the port number on which the management server listens for configuration requests and management commands.
[NDB_MGMD]LogDestination
This parameter specifies where to send cluster logging
information. There are three options in this regard:
CONSOLE
, SYSLOG
, and
FILE
:
CONSOLE
outputs the log to
stdout
:
CONSOLE
SYSLOG
sends the log to a
syslog
facility, possible values
being one of auth
,
authpriv
, cron
,
daemon
, ftp
,
kern
, lpr
,
mail
, news
,
syslog
, user
,
uucp
, local0
,
local1
, local2
,
local3
, local4
,
local5
, local6
,
or local7
.
Note: Not every facility is necessarily supported by every operating system.
SYSLOG:facility=syslog
FILE
pipes the cluster log output
to a regular file on the same machine. The following
values can be specified:
filename
: The name of the
logfile.
maxsize
: The maximum size to
which the file can grow before logging rolls over
to a new file. When this occurs, the old logfile
is renamed by appending .x
to
the filename, where x
is the
next number not yet used with this name.
maxfiles
: The maximum number of
logfiles.
FILE:filename=cluster.log,maxsize=1000000,maxfiles=6
It is possible to specify multiple log destinations as shown here, using a semicolon-delimited string:
CONSOLE;SYSLOG:facility=local0;FILE:filename=/var/log/mgmd
The default value for the FILE
parameter is
FILE:filename=ndb_
,
where node_id
_cluster.log,maxsize=1000000,maxfiles=6node_id
is the ID of the
node.
[NDB_MGMD]ArbitrationRank
This parameter is used to define which nodes can act as
arbitrators. Only MGM nodes and SQL nodes can be
arbitrators. ArbitrationRank
can take
one of the following values:
0
: The node will never be used as
an arbitrator.
1
: The node has high priority; that
is, it will be preferred as an arbitrator over
low-priority nodes.
2
: Indicates a low-priority node
which be used as an arbtrator only if a node with a
higher priority is not available for that purpose.
Normally, the management server should be configured as an
arbitrator by setting its
ArbitrationRank
to 1 (the default
value) and that of all SQL nodes to 0.
[NDB_MGMD]ArbitrationDelay
An integer value which causes the management server's responses to arbitration requests to be delayed by that number of milliseconds. By default, this value is 0; it is normally not necessary to change it.
[NDB_MGMD]DataDir
This sets the directory where output files from the
management server will be placed. These files include
cluster log files, process output files, and the daemon's
pid file. (For log files, this can be overridden by
setting the FILE
parameter for
[NDB_MGMD]LogDestination
as discussed
previously in this section.)
The [NDBD]
section is used to configure the
behavior of the cluster's data nodes. There are many
parameters which control buffer sizes, pool sizes, timeouts,
and so forth. The only mandatory parameters are:
Either ExecuteOnComputer
or
HostName
.
The parameter NoOfReplicas
These need to be defined in the [NDBD
DEFAULT]
section.
Most data node parameters are set in the [NDBD
DEFAULT]
section. Only those parameters explicitly
stated as being able to set local values are allowed to be
changed in the [NDBD]
section.
HostName
, Id
and
ExecuteOnComputer
must
be defined in the local [NDBD]
section.
Identifying Data Nodes
The Id
value (that is, the the data node
identifier) can be allocated on the command line when the node
is started or in the configuration file.
For each parameter it is possible to use k
,
M
, or G
as a suffix to
indicate units of 1024, 1024*1024, or 1024*1024*1024. (For
example, 100k
means 100 * 1024 = 102400.)
Parameters and values are currently case-sensitive.
[NBDB]Id
This is the node ID used as the address of the node for all cluster internal messages. This is an integer between 1 and 63. Each node in the cluster has a unique identity.
[NDBD]ExecuteOnComputer
This refers to one of the computers (hosts) defined in the
COMPUTER
section.
[NDBD]HostName
Specifying this parameter has an effect similar to
specifying ExecuteOnComputer
. It
defines the hostname of the computer the storage node on
which is to reside. Either this parameter or
ExecuteOnComputer
is required in order
to specify a hostname other than
localhost
.
(OBSOLETE)
[NDBD]ServerPort
Each node in the cluster uses a port to connect to other nodes. This port is used also for non-TCP transporters in the connection setup phase. Since, the default port is allocated dynamically in such a way as to ensure that no two nodes on the same computer receive the same port number, it should not normally be necessary to specify a value for this parameter.
[NDBD]NoOfReplicas
This global parameter can be set only in the
[NDBD DEFAULT]
section, and defines the
number of replicas for each table stored in the cluster.
This parameter also specifies the size of node groups. A
node group is a set of nodes all storing the same
information.
Node groups are formed implicitly. The first node group is
formed by the set of data nodes with the lowest node IDs,
the next node group by the set of the next lowest node
identities, and so on. By way of example, assume that we
have 4 data nodes and that NoOfReplicas
is set to 2. The four data nodes have node IDs 2, 3, 4 and
5. Then the first node group is formed from nodes 2 and 3,
and the second node group by nodes 4 and 5. It is
important to configure the cluster in such a manner that
nodes in the same node groups are not placed on the same
computer, as in this situation a single hardware failure
would cause the entire cluster to crash.
If no node IDs are provided then the order of the data
nodes will be the determining factor for the node group.
Whether or not explicit assignments are made, they can be
viewed in the output of the management client's
SHOW
command.
There is no default value for
NoOfReplicas
; the maximum possible
value is 4.
[NDBD]DataDir
This parameter specifies the directory where trace files, log files, pid files and error logs are placed.
[NDBD]FileSystemPath
This parameter specifies the directory where all files
created for metadata, REDO logs, UNDO logs and data files
are placed. The default is the directory specified by
DataDir
.
Note: This directory must
exist before the ndbd process is
initiated.
The recommended directory hierarchy for MySQL Cluster
includes /var/lib/mysql-cluster
,
under which a directory for the node's filesystem is
created. This subdirectory contains the node ID. For
example, if the node ID is 2, then this subdirectory is
named ndb_2_fs
.
[NDBD]BackupDataDir
It is also possible to specify the directory in which
backups are placed. By default, this directory is
.
(See above.)
FileSystemPath/
BACKUP
Data Memory and Index Memory
DataMemory
and
IndexMemory
are parameters specifying the
size of memory segments used to store the actual records and
their indexes. In setting values for these, it is important to
understand how DataMemory
and
IndexMemory
are used, as they usually need
to be updated in order to reflect actual usage by the cluster:
[NDBD]DataMemory
This parameter defines the amount of space available for storing database records. The entire amount is allocated in memory, so it is extremely important that the machine has sufficient physical memory to accomodate this value.
The memory allocated by DataMemory
is
used to store both the the actual records and indexes.
Each record is currently of fixed size. (Even
VARCHAR
columns are stored as
fixed-width columns.) There is a 16-byte overhead on each
record; an additional amount for each record is incurred
because it is stored in a 32KB page with 128 byte page
overhead (see below). There is also a small amount wasted
per page due to the fact that each record is stored in
only one page. The maximum record size is currently 8052
bytes.
The memory space defined by DataMemory
is also used to store ordered indexes, which use about 10
bytes per record. Each table row is represented in the
ordered index. A common error among users is to assume
that all indexes are stored in the memory allocated by
IndexMemory
, but this is not the case:
only primary key and unique hash indexes use this memory;
ordered indexes use the memory allocated by
DataMemory
. However, creating a primary
key or unique hash index also creates an ordered index on
the same keys, unless you specify USING
HASH
in the index creation statement. This can
be verified by running ndb_desc -d
db_name
table_name
in the
management client.
The memory space allocated by
DataMemory
consists of 32KB pages,
which are allocated to table fragments. Each table is
normally partitioned into the same number of fragments as
there are data nodes in the cluster. Thus, for each node,
there are the same number of fragments as are set in
NoOfReplicas
. Once a page has been
allocated, it is currently not possible to return it to
the pool of free pages, except by deleting the table.
Performing a node recovery also will compress the
partition because all records are inserted into empty
partitions from other live nodes.
The DataMemory
memory space also
contains UNDO information: For each update, a copy of the
unaltered record is allocated in the
DataMemory
. There is also a reference
to each copy in the ordered table indexes. Unique hash
indexes are updated only when the unique index columns are
updated, in which case a new entry in the index table is
inserted and the old entry is deleted upon commit. For
this reason, it is also necessary to allocate enough
memory to handle the largest transactions performed by
applications using the cluster. In any case, performing a
few large transactions holds no advantage over using many
smaller ones, for the following reasons:
Large transactions are not any faster than smaller ones
Large transactions increase the number of operations that are lost and must be repeated in event of transaction failure
Large transactions use more memory
The default value for DataMemory
is
80MB; the minimum is 1MB. There is no maximum size, but in
reality the maximum size has to be adapted so that the
process does not start swapping when the limit is reached.
This limit is determined by the amount of physical RAM
available on the machine and by the amount of memory that
the operating system may commit to any one process. 32-bit
operating systems are generally limited to 2-4GB per
process; 64-bit operating systems can use more. For large
databases, it may be preferable to use a 64-bit operating
system for this reason. In addition, it is also possible
to run more than one ndbd process per
machine, and this may prove advantageous on machines with
multiple CPUs.
[NDBD]IndexMemory
This parameter controls the amount of storage used for hash indexes in MySQL Cluster. Hash indexes are always used for primary key indexes, unique indexes, and unique constraints. Note that when defining a primary key and a unique index, two indexes will be created, one of which is a hash index used for all tuple accesses as well as lock handling. It is also used to enforce unique constraints.
The size of the hash index is 25 bytes per record, plus the size of the primary key. For primary keys larger than 32 bytes another 8 bytes is added.
Consider a table defined by
CREATE TABLE example ( a INT NOT NULL, b INT NOT NULL, c INT NOT NULL, PRIMARY KEY(a), UNIQUE(b) ) ENGINE=NDBCLUSTER;
There are 12 bytes overhead (having no nullable columns
saves 4 bytes of overhead) plus 12 bytes of data per
record. In addition we have two ordered indexes on columns
a
and b
consuming
roughly 10 bytes each per record. There is a primary key
hash index on the base table using roughly 29 bytes per
record. The unique constraint is implemented by a separate
table with b
as primary key and
a
as a column. This table will consume
an additional 29 bytes of index memory per record in the
example
table as well as 12 bytes of
overhead, plus 8 bytes of record data.
Thus, for one million records, we need 58 MB for index memory to handle the hash indexes for the primary key and the unique constraint. We also need 64 MB for the records of the base table and the unique index table, plus the two ordered index tables.
You can see that hash indexes takes up a fair amount of memory space; however, they provide very fast access to the data in return. They are also used in MySQL Cluster to handle uniqueness constraints.
Currently the only partitioning algorithm is hashing and ordered indexes are local to each node. Thus ordered indexes cannot be used to handle uniqueness constraints in the general case.
An important point for both IndexMemory
and DataMemory
is that the total
database size is the sum of all data memory and all index
memory for each node group. Each node group is used to
store replicated information, so if there are four nodes
with 2 replicas, then there will be two node groups. Thus,
the total data memory available is
2*DataMemory
for each data node.
It is highly recommended that
DataMemory
and
IndexMemory
be set to the same values
for all nodes. Since data is distributed evenly over all
nodes in the cluster the maximum amount of space available
for any node can be no greater than that of the smallest
node in the cluster.
DataMemory
and
IndexMemory
can be changed, but
decreasing either of these can be risky; doing so can
easily lead to a node or even an entire MySQL Cluster that
is unable to restart due to there being insufficient
memory space. Increasing these values should be
acceptable, but it is recommended that such upgrades are
performed in the same manner as a software upgrade,
beginning with an update of the configuration file, then
restarting the management server followed by restarting
each data node in turn.
Updates do not increase the amount of index memory used. Inserts take effect immediately; however, rows are not actually deleted until the transaction is committed.
The default value for IndexMemory
is
18MB. The minimum is 1MB.
Transaction Parameters
The next three parameters which we discuss are important
because they affect the number of parallel transactions and
the sizes of transactions that can be handled by the system.
MaxNoOfConcurrentTransactions
sets the
number of parallel transactions possible in a node;
MaxNoOfConcurrentOperations
sets the number
of records that can be in update phase or locked
simultaneously.
Both of these parameters (especially
MaxNoOfConcurrentOperations
) are likely
targets for users setting specific values and not using the
default value. The default value is set for systems using
small transactions, in order to ensure that these do not use
excessive memory.
[NDBD]MaxNoOfConcurrentTransactions
For each active transaction in the cluster there must be a record in one of the cluster nodes. The task of coordinating transactions is spread amongst the nodes: the total number of transaction records in the cluster is the number of transactions in any given node times the number of nodes in the cluster.
Transaction records are allocated to individual MySQL servers. Normally there is at least one transaction record allocated per connection that using any table in the cluster. For this reason, one should ensure that there are more transaction records in the cluster than there are concurrent connections to all MySQL servers in the cluster.
This parameter must be set to the same value for all cluster nodes.
Changing this parameter is never safe and doing so can cause a cluster to crash. When a node crashes one of the nodes (actually the oldest surviving node) will build up the transaction state of all transactions ongoing in the crashed node at the time of the crash. It is thus important that this node has as many transaction records as the failed node.
The default value for this parameter is 4096.
[NDBD]MaxNoOfConcurrentOperations
It is a good idea to adjust the value of this parameter according to the size and number of transactions. When performing transactions of only a few operations each and not involving a great many records, there is no need to set this parameter very high. When performing large transactions involving many records need to set this parameter higher.
Records are kept for each transaction updating cluster data, both in the transaction co-ordinator and in the nodes where the actual updates are performed. These records contain state information needed in order to find UNDO records for rollback, lock queues, and other purposes.
This parameter should be set to the number of records to be updated simultaneously in transactions, divided by the number of cluster data nodes. For example, in a cluster which has 4 data nodes and which is expected to handle 1,000,000 concurrent updates using transactions, you should set this value to 1000000 / 4 = 250000.
Read queries which set locks also cause operation records to be created. Some extra space is allocated within individual nodes to accomodate cases where the distribution is not perfect over the nodes.
When queries make use of the unique hash index, there are actually two operation records used per record in the transaction. The first record represents the read in the index table and the second handles the operation on the base table.
The default value for this parameter is 32768.
This parameter actually handles two values that can be configured separately. The first of these specifies how many operation records are to be placed with the transaction co-ordinator. The second part specifies how many operation records are to be local to the database.
A very large transaction performed on an 8-node cluster
requires as many operation records in the transaction
co-ordinator as there are reads, updates, and deletes
involved in the transaction. However, the operation
records of the are spread over all 8 nodes. Thus, if it is
necessary to configure the system for one very large
transaction, then it is a good idea to configure the two
parts separately.
MaxNoOfConcurrentOperations
will always
be used to calculate the number of operation records in
the transaction co-ordinator portion of the node.
It is also important to have an idea of the memory requirements for operation records. In MySQL 5.0, these consume about 1KB per record.
[NDBD]MaxNoOfLocalOperations
By default, this parameter is calculated as 1.1 *
MaxNoOfConcurrentOperations
which fits
systems with many simultaneous transactions, none of them
being very large. If there is a need to handle one very
large transaction at a time and there are many nodes, then
it is a good idea to override the default value by
explicitly specifying this parameter.
Transaction Temporary Storage
The next set of parameters is used to determine temporary storage when executing a query which is part of a Cluster transaction. All records are released when the query is completed and the cluster is waiting for the commit or rollback.
The default values for these parameters are adequate for most situations. However, users with a need to support transactions involving large numbers of rows or operations may need to increase these to enable better parallelism in the system, while users whose applications require relatively small transactions can decrease the values in order to save memory.
[NDBD]MaxNoOfConcurrentIndexOperations
For queries using a unique hash index another, temporary
set of operation records is used during a query's
execution phase. This parameter sets the size of that pool
of records. Thus this record is only allocated while
executing a part of a query, as soon as this part has been
executed the record is released. The state needed to
handle aborts and commits is handled by the normal
operation records where the pool size is set by the
parameter MaxNoOfConcurrentOperations
.
The default value of this parameter is 8192. Only in rare cases of extremely high parallelism using unique hash indexes should it be necessary to increase this value. Using a smaller value is possible and can save memory if the DBA is certain that a high degree parallelism is not required for the cluster.
[NDBD]MaxNoOfFiredTriggers
The default value of
MaxNoOfFiredTriggers
is 4000, which is
sufficient for most situations. In some cases it can even
be decreased if the DBA feels certain the need for
parallelism in the cluster is not high.
A record is created when an operation is performed that affects a unique hash index. Inserting or deleting a record in a table with unique hash indexes or updating a column that is part of a unique hash index fires an insert or a delete in the index table. The resulting record is used to represent this index table operation while waiting for the original operation that fired it to complete. This operation is short lived but can still require a large number of records in its pool for situations with many parallel write operations on a base table containing a set of unique hash indexes.
[NDBD]TransactionBufferMemory
The memory affected by this parameter is used for tracking operations fired when updating index tables and reading unique indexes. This memory is used to store the key and column information for these operations. It is only very rarely that the value for this parameter needs to be altered from the default.
Normal read and write operations use a similar buffer,
whose usage is even more short-lived. The compile-time
parameter ZATTRBUF_FILESIZE
(found in
ndb/src/kernel/blocks/Dbtc/Dbtc.hpp
)
set to 4000*128 bytes (500KB). A similar buffer for key
info, ZDATABUF_FILESIZE
(also in
Dbtc.hpp
) contains 4000 * 16 = 62.5KB
of buffer space. Dbtc
is the module
which handles transaction co-ordination.
Scans and Buffering
There are additional parameters in the
Dblqh
module (in
ndb/src/kernel/blocks/Dblqh/Dblqh.hpp
)
which affect reads and updates. These include
ZATTRINBUF_FILESIZE
, set by default to
10000*128 bytes (1250KB) and
ZDATABUF_FILE_SIZE
, set by default to
10000*16 bytes (roughly 156KB) of buffer space. To date,
there have been neither any reports from users nor any
results from our own extensive tests suggesting that either
of these compile-time limits should be increased.
The default value for
TransactionBufferMemory
is 1MB.
[NDBD]MaxNoOfConcurrentScans
This parameter is used to control the number of parallel
scans that can be performed in the cluster. Each
transaction co-ordinator can handle the number of parallel
scans defined for this parameter. Each scan query is
performed by scanning all partitions in parallel. Each
partition scan uses a scan record in the node where the
partition is located, the number of records being the
value of this parameter times the number of nodes. The
cluster should be able to sustain
MaxNoOfConcurrentScans
scans
concurrently from all nodes in the cluster.
Scans are actually performed in two cases. The first of these cases occurs when no hash or ordered indexes exists to handle the query, in which case the query is executed by performing a full table scan. The second case is encountered when there is no hash index to support the query but there is an ordered index. Using the ordered index means executing a parallel range scan. Since the order is kept on the local partitions only, it is necessary to perform the index scan on all partitions.
The default value of
MaxNoOfConcurrentScans
is 256. The
maximum value is 500.
This parameter specifies the number of scans possible in
the transaction co-ordinator. If the number of local scan
records is not provided, it is calculated as the product
of MaxNoOfConcurrentScans
and the
number of data nodes in the system.
[NDBD]MaxNoOfLocalScans
Specifies the number of local scan records if many scans are not fully parallelized.
[NDBD]BatchSizePerLocalScan
This parameter is used to calculate the number of lock records which needs to be there to handle many concurrent scan operations.
The default value is 64; this value has a strong
connection to the ScanBatchSize
defined
in the SQL nodes.
[NDBD]LongMessageBuffer
This is an internal buffer used for passing messages within individual nodes and between nodes. While it is highly unlikely that this would need to be changed, it is configurable. By default it is set to 1MB.
Logging and Checkpointing
[NDBD]NoOfFragmentLogFiles
This parameter sets the size of the node's REDO log files. REDO log files are organized in a ring. It is extremely important that the first and last log files (sometimes referred to as the “head” and “tail” log files, respectively) do not meet; when these approach one another too closely, the node will begin aborting all transactions encompassing updates due to a lack of room for new log records.
A REDO log record is not removed until three local checkpoints have been completed since that log record was inserted. Checkpointing frequency is determined by its own set of configuration parameters discussed elsewhere in this chapter.
The default parameter value is 8, which means 8 sets of 4
16MB files for a total of 512MB. In other words, REDO log
space must be allocated in blocks of 64MB. In scenarios
requiring a great many updates, the value for
NoOfFragmentLogFiles
may need to be set
as high as 300 or even higher in order to provide
sufficient space for REDO logs.
If the checkpointing is slow and there are so many writes
to the database that the log files are full and the log
tail cannot be cut without jeapo rdising recovery, then
all updating transactions will be aborted with internal
error code 410, or Out of log file space
temporarily
. This condition will prevail until a
checkpoint has completed and the log tail can be moved
forward.
[NDBD]MaxNoOfSavedMessages
This parameter sets the maximum number of trace files that will be kept before overwriting old ones. Trace files are generated when, for whatever reason, the node crashes.
The default is 25 trace files.
Metadata Objects
The next set of parameters defines pool sizes for metadata objects, used to define the maximum number of attributes, tables, indexes, and trigger objects used by indexes, events, and replication between clusters. Note that these act merely as “suggestions” to the cluster, and any that are not specified revert to the default values shown.
[NDBD]MaxNoOfAttributes
Defines the number of attributes that can be defined in the cluster.
The default value for this parameter is 1000, with the minimum possible value being 32. There is no maximum. Each attribute consumes around 200 bytes of storage per node due to the fact that all metadata is fully replicated on the servers.
When setting MaxNoOfAttributes
, it is
important to prepare in advance for any ALTER
TABLE
commands that you might wish to perform in
future. This is due to the fact, during the execution of
ALTER TABLE
on a Cluster table, 3 times
the number of attributes as in the original table are
used. For example, if a table requires 100 attributes, and
you wish to be able to alter it later, then you need to
set the value of MaxNoOfAttributes
to
300. A good rule of thumb is that, if you can create all
desired tables without any problems, then add 2 times the
number of attributes in the largest table to
MaxNoOfAttributes
to be sure. You
should also verify that this number is sufficient by
trying an actual ALTER TABLE
after
doing so. If this is not successful, increase
MaxNoOfAttributes
by another multiple
of the original value and test it again.
[NDBD]MaxNoOfTables
A table object is allocated for each table, unique hash index, and ordered index. This parameter sets the maximum number of table objects for the cluster as a whole.
For each attribute that has a BLOB
data
type an extra table is used to store most of the
BLOB
data. These tables also must be
taken into account when defining the total number of
tables.
The default value of this parameter is 128. The minimum is 8 and the maximum is 1600. Each table object consumes approximately 20KB per node.
[NDBD]MaxNoOfOrderedIndexes
For each ordered index in the cluster, an object is allocated describing what is being indexed and its storage segments. By default each index so defined also defines an ordered index. Each unique index and primary key has both an ordered index and a hash index.
The default value of this parameter is 128. Each object consumes approximately 10KB of data per node.
[NDBD]MaxNoOfUniqueHashIndexes
For each unique index that is not a primary key, a special
table is allocated that maps the unique key to the primary
key of the indexed table. By default there an ordered
index is also defined for each unique index. To prevent
this, you must use the USING HASH
option when defining the unique index.
The default value is 64. Each index consumes approximately 15KB per node.
[NDBD]MaxNoOfTriggers
Internal update, insert, and delete triggers are allocated for each unique hash index. (This means that 3 triggers are created for each unique hash index.) However, an ordered index requires only a single trigger object. Backups also use three trigger objects for each normal table in the cluster.
Note: When replication between clusters is supported, this will also make use of internal triggers.
This parameter sets the maximum number of trigger objects in the cluster.
The default value for this parameter is 768.
[NDBD]MaxNoOfIndexes
This parameter is deprecated in MySQL 5.0;
you should use MaxNoOfOrderedIndexes
and MaxNoOfUniqueHashIndexes
instead.
This parameter is used only by unique hash indexes. There needs to be one record in this pool for each unique hash index defined in the cluster.
The default value of this parameter is 128.
Boolean Parameters
The behavior of data nodes is also affected by a set of
parameters taking on boolean values. These parameters can each
be specified as TRUE
by setting them equal
to 1
or Y
, and as
FALSE
by setting them equal to
0
or N
.
[NDBD]LockPagesInMainMemory
For a number of operating systems, including Solaris and Linux, it is possible to lock a process into memory and so avoid any swapping to disk. This can be used to help guarantee the cluster's real-time characteristics.
By default, this feature is disabled.
[NDBD]StopOnError
This parameter specifies whether an NDBD process is to exit or to perform an automatic restart when an error condition is encountered.
This feature is enabled by default.
[NDBD]Diskless
It is possible to specify MySQL Cluster tables as diskless, meaning that tables are not checkpointed to disk and that no logging occurs. Such tables exist only in main memory. A consequence of using diskless tables is that neither the tables nor the records in those tables will be preserved after a crash. However, when operating in diskless mode, it is possible to run ndbd on a diskless computer.
Note that in MySQL 5.0 this feature causes the entire cluster to operate in diskless mode. In addition, when this feature is enabled, backups are performed but backup data is not actually stored.
When this feature is enabled, backups are performed but backup data is not actually stored.
This feature is enabled by setting
Diskless
to either 1
or Y
. Diskless
is
disabled by default.
[NDBD]RestartOnErrorInsert
This feature is accessible only when building the debug version where it is possible to insert errors in the execution of individual blocks of code as part of testing.
By default, this feature is disabled.
Controlling Timeouts, Intervals, and Disk Paging
There are a number of parameters specifying timeouts and intervals between various actions in Cluster data nodes. Most of the timeout values are specified in milliseconds. Any exceptions to this will be mentioned where applicable below.
[NDBD]TimeBetweenWatchDogCheck
To prevent the main thread from getting stuck in an endless loop at some point, a “watchdog” thread checks the main thread. This parameter specifies the number of milliseconds between checks. If the process remains in the same state after three checks, it is terminated by the watchdog thread.
This parameter can easily be changed for purposes of experimentation or to adapt to local conditions. It can be specified on a per-node basis although there seems to be little reason for doing so.
The default timeout is 4000 milliseconds (4 seconds).
[NDBD]StartPartialTimeout
This parameter specifies the time that the cluster will wait for all storage nodes to come up before the cluster initialization routine is invoked. This timeout is used to avoid a partial Cluster startup whenever possible.
The default value is 30000 milliseconds (30 seconds).
0
means eternal time out; in other
words, the cluster may start only if all nodes are
available.
[NDBD]StartPartitionedTimeout
If the cluster is ready to start after waiting for
StartPartialTimeout
milliseconds but is
still possibly in a partitioned state, the cluster waits
until this timeout has also passed.
The default timeout is 60000 milliseconds (60 seconds).
[NDBD]StartFailureTimeout
If a data node has not completed its startup sequence
within the time specified by this parameter, then the node
startup will fail. Setting this parameter to
0
means that no data node timeout is
applied.
The default value is 60000 milliseconds (60 seconds). For data nodes containing extremely large amounts of data, this parameter should be increased. For example, in the case of a storage node containing several gigabytes of data, a period as long as 10-15 minutes (that is, 600,000 to 1,000,000 milliseconds) might be required in order to to perform a node restart.
[NDBD]HeartbeatIntervalDbDb
One of the primary methods of discovering failed nodes is by the use of heartbeats. This parameter states how often heartbeat signals are sent and how often to expect to receive them. After missing three heartbeat intervals in a row, the node is declared dead. Thus the maximum time for discovering a failure through the heartbeat mechanism is four times the heartbeat interval.
The default heartbeat interval is 1500 milliseconds (1.5 seconds). This parameter must not be changed drastically and should not vary widely between nodes. If one node uses 5000 milliseconds and the node watching it uses 1000 milliseconds then obviously the node will be declared dead very quickly. This parameter can be changed during an online software upgrade but only in small increments.
[NDBD]HeartbeatIntervalDbApi
Each data node sends heartbeat signals to each MySQL
server (SQL node) to ensure that it remains in contact. If
a MySQL server fails to send a heartbeat in time it is
declared “dead”, in which case all ongoing
transactions are completed and all resources released. The
SQL node cannot reconnect until all activities initiated
by the previous MySQL instance have been completed. The
three-heartbeat criteria for this determination are the
same as described for
HeartbeatIntervalDbDb
.
The default interval is 1500 milliseconds (1.5 seconds). This interval can vary between indidivual data nodes because each storage node watches the MySQL servers connected to it, independently of all other data nodes.
[NDBD]TimeBetweenLocalCheckpoints
This parameter is an exception in that it does not specify a time to wait before starting a new local checkpoint; rather, it is used to ensure that local checkpoints are not performed in a cluster where relatively few updates are taking place. In most clusters with high update rates, it is likely that a new local checkpoint is started immediately after the previous one has been completed.
The size of all write operations executed since the start of the previous local checkpoints is added. This parameter is also exceptional in that it is specified as the base-2 logarithm of the number of 4-byte words, so that the default value 20 means 4MB (4 × 220) of write operations, 21 would mean 8MB, and so on up to a maximum value of 31, which equates to 8GB of write operations.
All the write operations in the cluster are added
together. Setting
TimeBetweenLocalCheckpoints
to 6 or
less means that local checkpoints will be executed
continuously without pause, independent of the cluster's
workload.
[NDBD]TimeBetweenGlobalCheckpoints
When a transaction is committed, it is committed in main memory in all nodes on which the data is mirrored. However, transaction log records are not flushed to disk as part of the commit. The reasoning behing this behavior is that having the transaction safely committed on at least two autonomous host machines should meet reasonable standards for durability.
It is also important to ensure that even the worst of cases — a complete crash of the cluster — is handled properly. To guarantee that this happens, all transactions taking place within a given interval are put into a global checkpoint, which can be thought of as a set of committed transactions that has been flushed to disk. In other words, as part of the commit process, a transaction is placed in a global checkpoint group; later, this group's log records are flushed to disk, and then the entire group of transactions is safely committed to disk on all computers in the cluster.
This parameter defines the interval between global checkpoints. The default is 2000 milliseconds.
[NDBD]TimeBetweenInactiveTransactionAbortCheck
Time-out handling is performed by checking a timer on each transaction once for every interval specified by this parameter. Thus, if this parameter is set to 1000 milliseconds, then every transaction will be checked for timing out once per second.
The default value for this parameter is 1000 milliseconds (1 second).
[NDBD]TransactionInactiveTimeout
If the transaction is currently not performing any queries but is waiting for further user input, this parameter states the maximum time that the user can wait before the transaction is aborted.
The default for this parameter is zero (no timeout). For a real-time database that needs to ensure that no transaction keeps locks for too long a time this parameter should be set to a much smaller value. The unit is milliseconds.
[NDBD]TransactionDeadlockDetectionTimeout
When a node executes a query involving a transaction, the node waits for the other nodes in the cluster to respond before continuing. A failure to respond can occur for any of the following reasons:
The node is “dead”
The operation has entered a lock queue
The node requested to perform the action could be heavily overloaded.
This timeout parameter states how long the transaction coordinator will wait for query execution by another node before aborting the transaction, and is important for both node failure handling and deadlock detection. Setting it too high can cause a undesirable behavior in situations involving deadlocks and node failure.
The default timeout value is 1200 milliseconds (1.2 seconds).
[NDBD]NoOfDiskPagesToDiskAfterRestartTUP
When executing a local checkpoint the algorithm flushes
all data pages to disk. Merely doing as quickly as
possible without any moderation is likely to impose
excessive loads on processors, networks, and disks. To
control the write speed, this parameter specifies how many
pages per 100 milliseconds are to be written. In this
context, a “page” is defined as 8KB; thus,
this parameter is specified in units of 80KB per second.
Therefore, setting
NoOfDiskPagesToDiskAfterRestartTUP
to a
value of 20
entails writing 1.6MB in
data pages to disk each second during a local checkpoint.
This value includes the writing of UNDO log records for
data pages; that is, this parameter handles the limitation
of writes from data memory. UNDO log records for index
pages are handled by the parameter
NoOfDiskPagesToDiskAfterRestartACC
.
(See the entry for IndexMemory
for
information about index pages.)
In short, this parameter specifies how quickly local
checkpoints will be executed, and operates in conjunction
with NoOfFragmentLogFiles
,
DataMemory
, and
IndexMemory
.
The default value is 40 (3.2MB of data pages per second).
[NDBD]NoOfDiskPagesToDiskAfterRestartACC
This parameter uses the same units as
NoOfDiskPagesToDiskAfterRestartTUP
and
acts in a similar fashion, but limits the speed of writing
index pages from index memory.
The default value of this parameter is 20 index memory pages per second (1.6MB per second).
[NDBD]NoOfDiskPagesToDiskDuringRestartTUP
This parameter in a similar fashion as
NoOfDiskPagesToDiskAfterRestartTUP
and
NoOfDiskPagesToDiskAfterRestartACC
,
only it does so with regard to local checkpoints executed
in the node when a node is restarting. As part of all node
restarts a local checkpoint is always performed. During a
node restart it is possible to write to disk at a higher
speed than at other times, because fewer activities are
being performed in the node.
This parameter covers pages written from data memory.
The default value is 40 (3.2MB per second).
[NDBD]NoOfDiskPagesToDiskDuringRestartACC
Controls the number of index memory pages that can be written to disk during the loca checkpoint phase of a node restart.
As with
NoOfDiskPagesToDiskAfterRestartTUP
and
NoOfDiskPagesToDiskAfterRestartACC
,
values for this parameter are expressed in terms of 8KB
pages written per 100 milliseconds (80KB/second).
The default value is 20 (1.6MB per second).
[NDBD]ArbitrationTimeout
This parameter specifies the time that the data node will wait for a response from the arbitrator to an arbitration message. If this is exceeded, then it is assumed that the network has split.
The default value is 1000 milliseconds (1 second).
Buffering and Logging
Several configuration parameters corresponding to former compile-time parameters are also available. These enable the advanced user to have more control over the resources used by node processes and to adjust various buffer sizes at need.
These buffers are used as front-ends to the file system when
writing log records to disk. If the node is running in
diskless mode, then these parameters can be set to their
minimum values without penalty due to the fact that disk
writes are “faked” by the NDB
storage engine's filesystem abstraction layer.
[NDBD]UndoIndexBuffer
This buffer is used during local checkpoints. The
NDB
storage engine uses a recovery
scheme based on checkpoint consistency in conjunction with
an operational REDO log. In order to produce a consistent
checkpoint without blocking the entire system for writes,
UNDO logging is done while performing the local
checkpoint. UNDO logging is activated on a single table
fragment at a time. This optimization is possible because
tables are stored entirely in main memory.
The UNDO index buffer buffer is used for the updates on the primary key hash index. Inserts and deletes rearrange the hash index; the NDB storage engine writes UNDO log records that map all physical changes to an index page so that they can be undone at system restart. It also logs all active insert operations for each fragment at the start of a local checkpoint.
Reads and updates set lock bits and update a header in the hash index entry. These changes are handled by the page-writing algorithm to insure that these operations need no UNDO logging.
This buffer is 2MB by default. The minimum value is 1MB,
and for most applications the minimum is sufficient. For
applications doing extremely large and/or numerous inserts
and deletes together with large transactions and large
primary keys, it may be necessary to increase the size of
this buffer. If this buffer is too small, the NDB storage
engine issues internal error code 677 Index UNDO
buffers overloaded
.
[NDBD]UndoDataBuffer
The UNDO data buffer plays the same role as the UNDO index buffer, except that it is used with regard to data memory rather than index memory. This buffer is used during the local checkpoint phase of a fragment for inserts, deletes, and updates.
Since UNDO log entries tend to grow larger as more operations are logged, this buffer is also larger than its index memory counterpart, with a default value of 16MB.
For some applications this amount of memory may be unnecessarily large. In such cases it is possible to decrease this size down to a minimum of 1MB.
It is rarely necessary to increase the size of this buffer. If there is such a need, then it is a good idea to check if the disks can actually handle the load caused by database update activity. A lack of sufficient disk space cannot be overcome by increasing the size of this buffer.
If this buffer is too small and gets congested, the NDB
storage engine issues internal error code 891
Data UNDO buffers overloaded
.
[NDBD]RedoBuffer
All update activities also need to be logged. This log makes it possible to replay these updates whenever the system is restarted. The NDB recovery algorithm uses a "fuzzy" checkpoint of the data together with the UNDO log, then applies the REDO log to play back all changes up to the restoration point.
This buffer is 8MB by default. The minimum value is 1MB.
If this buffer is too small, the NDB storage engine issues
error code 1221 REDO log buffers
overloaded
.
In managing the cluster, it is very important to be able to
control the number of log messages sent for various event
types to stdout
. There are 16 possible
event levels (numbered 0 through 15). Setting event reporting
for a given event category to level 15 means all event reports
in that category are sent to stdout
;
setting it to 0 means that there will be no event reports made
in that category.
By default, only the startup message is sent to
stdout
, with the reaimaining event
reporting level defaults being set to 0. The reason for this
is that these messages are also sent to the management
server's cluster log.
An analogous set of levels can be set for the management client to determine which event levels to record in the cluster log.
[NDBD]LogLevelStartup
Reporting level for events generated during startup of the process.
The default level is 1.
[NDBD]LogLevelShutdown
Reporting level for events generated as part of graceful shutdown of a node.
The default level is 0.
[NDBD]LogLevelStatistic
Reporting level for statistical events such as number of primary key reads, number of updates, number of inserts, information relating to buffer usage, and so on.
The default level is 0.
[NDBD]LogLevelCheckpoint
Reporting level for events generated by local and global checkpoints.
The default level is 0.
[NDBD]LogLevelNodeRestart
Reporting level for events generated during node restart.
The default level is 0.
[NDBD]LogLevelConnection
Reporting level for events generated by connections between cluster nodes.
The default level is 0.
[NDBD]LogLevelError
Reporting level for events generated by errors and warnings by the cluster as a whole. These errors do not cause any node failure but are still considered worth reporting.
The default level is 0.
[NDBD]LogLevelInfo
Reporting level for events generated for information about the general state of the cluster.
The default level is 0.
Backup Parameters
The parameters discussed in this section define memory buffers set aside for execution of online backups.
[NDBD]BackupDataBufferSize
In creating a backup, there are two buffers used for
sending data to the disk. The backup data buffer buffer is
used to fill in data recorded by scanning a node's tables.
Once this buffer has been filled to the level specified as
BackupWriteSize
(see below), the pages
are sent to disk. While flushing data to disk, the backup
process can continue filling this buffer until it runs out
of space. When this happens, the backup process pauses the
scan and waits until some disk writes have completed and
have thus freed up memory so that scanning may continue.
The default value for this parameter is 2MB.
[NDBD]BackupLogBufferSize
The backup log buffer fulfils a role similar to that played by the backup data buffer, except that it used for generating a log of all table writes made during execution of the backup. The same principles apply for writing these pages as with the backup data buffer, except that when there is no more space in the backup log buffer, the backup fails. For that reason, the size of the back up logbuffer must be big enough to handle the load caused by write activities while the backup is being made.
The default value for this parameter should be sufficient for most applications. In fact, it is more likely for a backup failure to be caused by insufficient disk write speed than it is for the backup log buffer to become full. If the disk subsystem is not configured for the write load caused by applications, the cluster will be likely to be able to perform the desired operations.
It is preferable to configure cluster nodes in such a manner that the processor becomes the bottleneck rather than the disks or the network connections.
The default value is 2MB.
[NDBD]BackupMemory
This parameter is simply the sum of
BackupDataBufferSize
and
BackupLogBufferSize
.
The default value is 2MB + 2MB = 4MB.
[NDBD]BackupWriteSize
This parameter specifies the size of messages written to disk by the backup log and backup data buffers.
The default value is 32KB.
The [MYSQLD]
sections in the
config.ini
file define the behavior of
the MySQL servers (SQL nodes) used to access cluster data.
None of the parameters shown is required. If no computer or
host name is provided, then any host can use this SQL node.
[MYSQLD]Id
This value is used as the address of the node by all cluster internal messages, and must be an integer between 1 and 63. Each cluster node must have a unique identity within the cluster.
[MYSQLD]ExecuteOnComputer
This refers to one of the computers (hosts) defined in a
[COMPUTER]
section of the configuration
file.
[MYSQLD]ArbitrationRank
This parameter is used to define which nodes can act as
arbitrators. Both MGM nodes and SQL nodes can be
arbitrators. A value of 0
means that
the given node will never be used as an arbitrator, a
value of 1
gives the node high priority
as an arbitrator, and a value of 2
gives it low priority. A normal configuration uses the
management server as arbitrator, setting its
ArbitrationRank
to 1
(the default) and those for all SQL nodes to
0
.
[MYSQLD]ArbitrationDelay
Setting this parameter to any other value than 0 (the default) means that responses by the arbitrator to arbitration requests will be delayed by the stated number of milliseconds. It is usually not necessary to change this value.
[MYSQLD]BatchByteSize
For queries that are translated into full table scans or
range scans on indexes, it is important for best
performance to fetch records in properly sized batches. It
is possible to set the proper size both in terms of number
of records (BatchSize
) and in terms of
bytes (BatchByteSize
). The actual batch
size will be limited by both parameters.
The spped at which queries are performed can vary by more than 40% depending upon how this parameter is set. In future releases, the MySQL Server will make educated guesses on how to set parameters relating to batch size, based on the query type.
This parameter is measured in bytes and by default is equal to 32KB.
[MYSQLD]BatchSize
This parameter is measured in number of records and is by default set to 64. The maximum size is 992.
[MYSQLD]MaxScanBatchSize
The batch size is the size of each batch sent from each data node. Most scans are performed in parallel in order to protect the MySQL Server from receiving too much data from many nodes in parallel; this parameter sets a limit to the total batch size over all nodes.
The default value of this parameter is set to 256KB. Its maximum size is 16MB.
TCP/IP is the default transport mechanism for establishing connections in MySQL Cluster. It is normally not necessary to define connections because Cluster automatically set ups a connection between each of the data nodes, between each data node and all MySQL server nodes, and between each data node and the management server. (For one exception to this rule, see Section 16.4.4.8, “MySQL Cluster TCP/IP Connections Using Direct Connections”.)
It is only necessary to define a connection in order to
override the default connection parameters. In that case it is
necessary to define at least
NodeId1
,
NodeId2
, and the parameters to
change.
It is also possible to change the default values for these
parameters by setting them in the [TCP
DEFAULT]
section.
[TCP]
,
NodeId1
[TCP]
NodeId2
To identify a connection between two nodes it is necessary
to provide the node identities for both of them in the
[TCP]
section of the configuration
file.
[TCP]SendBufferMemory
TCP transporters use a buffer to store all messages before performing the send call to the operating system. When this buffer reaches 64KB its contents are sent; these are also sent when a round of messages have been executed. To handle temporary overload situations it is also possible to define a bigger send buffer. The default size of the send buffer is 256KB.
[TCP]SendSignalId
In order to be able to retrace a distributed message
diagram it is necessary to identify each message. When
this parameter is set to Y
, message IDs
are transported over the network. This feature is disabled
by default.
[TCP]Checksum
This parameter is also a boolean
(Y
/N
or
1
/0
) parameter, and
is disabled by default. When it is enabled, checksums for
all messages are calculated before they placed in the send
buffer. This feature insures that messages are not
corrupted while waiting in the send buffer, or by the
transport mechanism.
[TCP]PortNumber
(OBSOLETE.) This formerly specified the port number to be used for listening for connections from other nodes. This parameter should no longer be used.
[TCP]ReceiveBufferMemory
Specifies the size of the buffer used when receiving data from the TCP/IP socket. There is seldom any need to change this parameter from its default value of 64KB, except possibly in order to save memory.
Setting up a cluster using direct connections between data
nodes requires specifying explicitly the crossover IP
addresses of the data nodes so connected in the
[TCP]
section of the cluster
config.ini
file.
In the following example, we envision a cluster with at least
4 hosts, one each for a management server, an SQL node, and
two data nodes. The cluster as a whole resides on the
172.23.72.*
subnet of a LAN. In addition to
the usual network connections, the two data nodes are
connected directly using a standard crossover cable, and
communicate with one another directly using IP addresses in
the 1.1.0.*
address range as shown:
# Management Server [NDB_MGMD] Id=1 HostName=172.23.72.20 # SQL Node [MYSQLD] Id=2 HostName=172.23.72.21 # Data Nodes [NDBD] Id=3 HostName=172.23.72.22 [NDBD] Id=4 HostName=172.23.72.23 # TCP/IP Connections [TCP] NodeId1=3 NodeId2=4 HostName1=1.1.0.1 HostName2=1.1.0.2
The use of direct connections between data nodes can improve the cluster's overall efficiency by allowing the data nodes to bypass an Ethernet device such as a switch, hub, or router, thus cutting down on the cluster's latency. It is important to note that in order to take the best advantage of direct connections in this fashion with more than 2 data nodes, you will need to have a direct connection between each data node and every other data node in the same node group.
In MySQL 5.0, MySQL Cluster attempts to use the
shared memory transporter and configure it automatically where
possible, chiefly where more than one node runs concurrently
on the same cluster host. (In previous versions of MySQL
Cluster, shared memory segments were supported only when the
-max
binary was built using
--with-ndb-shm
.) When explicitly defining
shared memory as the connection method, it is necessary to
define at least NodeId1
,
NodeId2
and ShmKey
. All
other parameters have default values that will work out fine
in most cases.
Note: SHM support should still be considered experimental.
[SHM]NodeId1
,
[SHM]NodeId2
To identify a connection between two nodes it is necessary
to provide node identifiers for each of them, as
NodeId1
and NodeId2
.
[SHM]ShmKey
When setting up shared memory segments, a node ID is used to identify uniquely the shared memory segment to use for the communication. This is expressed as an integer which does not have a default value.
[SHM]ShmSize
Each SHM connection has a shared memory segment where
messages between nodes are placed by the sender and read
by the reader. The size of this segment is defined by
ShmSize
. The default value is 1MB.
[SHM]SendSignalId
In order to retrace the path of a distributed message, it
is necessary to provide each message with a unique
identifier. Setting this parameter to Y
causes these message IDs to be transported over the
network as well. This feature is disabled by default.
[SHM]Checksum
This parameter is also a
Y
/N
parameter which
is disabled by default. When it is enabled, checksums for
all messages are calculated before being placed in the
send buffer.
This feature prevents messages from being corrupted while waiting in the send buffer. It also serves as a check against data being corrupted during transport.
Using SCI transporters to connect nodes in a MySQL Cluster is
supported only when the MySQL-Max binaries are built using
--with-ndb-sci=
.
The /your/path/to/SCI
path
should point to a
directory that contains at a minimum lib
and include
directories containing SISCI
libraries and header files.
In addition, SCI requires specialized hardware.
It is strongly recommended to use SCI Transporters only for communication between ndbd processes. Note also that using SCI Transporters means that the ndbd processes never sleep. For this reason, SCI Transporters should be used only on machines having at least 2 CPUs dedicated for use by ndbd processes. There should be at least 1 CPU per ndbd process, with at least 1 CPU left in reserve to handle operating system activities.
[SCI]NodeId1
,
[SCI]NodeId2
To identify a connection between two nodes it is necessary
to provide node identifiers for each of them, as
NodeId1
and NodeId2
.
[SCI]Host1SciId0
This identifies the SCI node ID on the first Cluster node
(identified by NodeId1
).
[SCI]Host1SciId1
It is possible to set up SCI Transporters for failover between two SCI cards which then should use separate networks between the nodes. This identifies the node ID and the second SCI card to be used on the first node.
[SCI]Host2SciId0
This identifies the SCI node ID on the second Cluster node
(identified by NodeId2
).
[SCI]Host2SciId1
When using two SCI cards to provide failover, this parameter identifies the second SCI card to be used on the second node.
[SCI]SharedBufferSize
Each SCI transporter has a shared memory segment used for communication between the two nodes. Setting the size of this segment to the default value of 1 MB should be sufficient for most applications. Using a smaller value can lead to problems when performing many parallel inserts; if the shared buffer is too small, this can also result in a crash of the ndbd process.
[SCI]SendLimit
A small buffer in front of the SCI media stores messages before transmitting them over the SCI network. By default this is set to 8kB. Our benchmarks show that performance is best at 64 kB but 16kB reaches within a few percent of this, and there was little if any advantage to increasing it beyond 8kB.
[SCI]SendSignalId
In order to trace a distributed message it is necessary to
identify each message uniquely. When this parameter is set
to Y
, message IDs are transported over
the network. This feature is disabled by default.
[SCI]Checksum
This parameter is also a boolean value, and is disabled by
default. When Checksum
is enabled,
checksums are calculated for all messages before they are
placed in the send buffer. This feature prevents messages
from being corrupted while waiting in the send buffer. It
also serves as a check against data being corrupted during
transport.
Understanding how to manage MySQL Cluster requires a knowledge of four essential processes. In the next few sections of this chapter, we cover the roles played by these processes in a cluster, how to use them, and what startup options are available for each of them.
mysqld is the traditional MySQL server
process. To be used with MySQL Cluster,
mysqld needs to be built with support for the
NDB Cluster
storage engine, as it is in the
precompiled -max
binaries available from
http://dev.mysql.com/downloads.
If the mysqld binary has been built in such a
manner, the NDB Cluster
storage engine is
still disabled by default. You can use either of two possible
options for enabling the NDB Cluster
storage
engine:
Use --ndbcluster
as a startup option when
starting mysqld
Insert a line containing ndbcluster
in
the [mysqld]
section of your
my.cnf
file.
An easy way to verify that your server is running with the
NDB Cluster
storage engine enabled is to
issue the command SHOW ENGINES
in the MySQL
Monitor (mysql). You should see the value
YES
in the row listing
NDBCLUSTER
; if you see NO
in this row (or if there is no such row displayed in the
output), you are not running an NDB
-enabled
version of MySQL. If you see DISABLED
in this
row, then you need to enable it in either one of the two ways
shown above.
In order to read cluster configuration data, the MySQL server requires at a minimum 3 pieces of information:
The MySQL server's own cluster node ID.
The hostname or IP address for the management server (MGM node).
The port on which it can connect to the management server.
Node IDs can be dynamically allocated in MySQL 5.0, so it is not strictly necessary to specify them explicitly.
The mysqld parameter
ndb-connectstring
is used to specify the
connectstring either on the command line when starting
mysqld or in my.cnf
. The
connectstring contains the hostname or IP address as well as the
port where the management server can be found.
In the following example, ndb_mgmd.mysql.com
is the host where the management server resides, and the
management server listens for cluster messages on port 1186:
shell> mysqld --ndb-connectstring=ndb_mgmd.mysql.com:1186
See Section 16.4.4.2, “The MySQL Cluster connectstring
” for more info
on connectstrings.
Given this information, the MySQL server will be a full participant in the cluster. (We sometimes refer to a mysqld process running in this manner as an SQL node.) It will be fully aware of all cluster data nodes as well as their status, and will establish connections to all data nodes. In this case, it is able to use any data node as a transaction coordinator and to access node data for reading and updating.
ndbd is the process that is used to handle all the data in tables using the NDB Cluster storage engine. This is the process empowers a storage node to accomplish distributed transaction handling, node recovery, checkpointing to disk, online backup, and related tasks.
In a MySQL Cluster, a set of ndbd processes co-operate in handling data. These processes can execute on the same computer (host) or on different computers. The correspondences between data nodes and Cluster hosts is completely configurable.
In MySQL 5.0, ndbd generates a
set of log files which are placed in the directory specified by
DataDir
in the configuration file. These log
files are listed below. Note that
node_id
represents the node's unique
identifier. For example, ndb_2_error.log
is
the error log generated by the storage node whose node ID is
2.
ndb_
is a file containing records of all crashes which the
referenced ndbd process has encountered.
Each record in this file contains a brief error string and a
reference to a trace file for this crash. A typical entry in
this file might appear as shown here:
node_id
_error.log
Date/Time: Saturday 30 July 2004 - 00:20:01 Type of error: error Message: Internal program error (failed ndbrequire) Fault ID: 2341 Problem data: DbtupFixAlloc.cpp Object of reference: DBTUP (Line: 173) ProgramName: NDB Kernel ProcessID: 14909 TraceFile: ndb_2_trace.log.2 ***EOM***
Note: It is very
important to be aware that the last entry in the error log
file is not necessarily the newest one (nor is it
likely to be). Entries in the error log are
not listed in chronological order;
rather, they correspond to the order of the trace files as
determined in the
ndb_
file (see below). Error log entries are thus overwritten in
a cyclical and not sequential fashion.
node_id
_trace.log.next
ndb_
is a trace file describing exactly what happened just before
the error occurred. This information is useful for analysis
by the MySQL Cluster development team.
node_id
_trace.log.trace_id
It is possible to configure the number of these trace files
that will be created before old files are overwritten.
trace_id
is a number which is
incremented for each successive trace file.
ndb_
is the file that keeps track of the next trace file number
to be assigned.
node_id
_trace.log.next
ndb_
is a file containing any data output by the
ndbd process. This file is created only
if ndbd is started as a daemon.
node_id
_out.log
ndb_
is a file containing the process ID of the
ndbd process when started as a daemon. It
also functions as a lock file to avoid the starting of nodes
with the same identifier.
node_id
.pid
ndb_
is a file used only in debug versions of
ndbd, where it is possible to trace all
incoming, outgoing, and internal messages with their data in
the ndbd process.
node_id
_signal.log
It is recommended not to use a directory mounted through NFS because in some environments this can cause problems whereby the lock on the pid-file remains in effect even after the process has terminated.
When starting ndbd it may also be necessary to specify the hostname of the management server and the port on which it is listening. Optionally, one may also specify the node ID that the process is to use.
shell> ndbd --connect-string="nodeid=2;host=ndb_mgmd.mysql.com:1186"
See Section 16.4.4.2, “The MySQL Cluster connectstring
” for additional
information about this issue.
When ndbd starts, it actually initiates two processes. The first of these is called the “angel process”; its only job is to discover when the execution process has been completed, and then to restart the ndbd process if it is configured to do so. Thus, if you attempt to kill ndbd via the Unix kill command, it is necessary to kill both processes. A more proper way to terminate an ndbd process is to use the management client and stop the process from there.
The execution process uses one thread for reading, writing, and scanning data, as well as all other activities. This thread is implemented asynchronously so that it can easily handle thousands of concurrent activites. In addition, a watch-dog thread supervises the execution thread to make sure that it does not hang in an endless loop. A pool of threads handles file I/O, with each thread able to handle one open file. Threads can also be used for transporter connections by the transporters in the ndbd process. In a system performing a large number of operations, including updates, the ndbd process can consume up to 2 CPUs if permitted to do so. For a machine with many CPUs it is recommended to use several ndbd processes which belong to different node groups.
The management server is the process that reads the cluster configuration file and distributes this information to all nodes in the cluster that request it. It also maintains a log of cluster activities. Management clients can connect to the management server and check the cluster's status.
It is not strictly necessary to specify a connectstring when starting the management server. However, if you are using more than one management server, a connectstring should be provided and each node in the cluster should specify its node ID explicitly.
The following files are created or used by
ndb_mgmd in its starting directory. In MySQL
5.0 Cluster, the log and PID files are placed in
the DataDir
as specified in the configuration
file. In the list that follows,
node_id
is the unique node
identifier.
config.ini
is the configuration file
for the cluster as a whole. This file is created by the user
and read by the management server. Setting up this file is
discussed in Section 16.4, “MySQL Cluster Configuration”.
ndb_
is the cluster events log file. Examples of such events
include checkpoint startup and completion, node startup
events, node failures, and levels of memory usage. A
complete listing of cluster events with descriptions may be
found in Section 16.6, “Management of MySQL Cluster”.
node_id
_cluster.log
When the size of the cluster log reaches one million bytes
then the file is renamed to
ndb_
,
where node_id
_cluster.log.seq_id
seq_id
is the sequence
number of the cluster log file. (For example: If 1, 2, and 3
already exist, the next log file will be named using the
number 4
.)
ndb_
is the file used for node_id
_out.logstdout
and
stderr
when running the management server
as a daemon.
ndb_
is the PID file used when running the management server as a
daemon.
node_id
.pid
The management client process is actually not needed to run the cluster. Its value lies in providing a set of commands for checking the cluster's status, starting backups, and performing other administrative functions. The management client access the management server using a C API that advanced users can also employ for programming dedicated management processes which can perform tasks similar to those performed by ndb_mgm.
When starting the management client, it is necessary to supply
the hostname and port of the management server as in the example
below. The default values in MySQL 5.0 are
localhost
and 1186
.
shell> ndb_mgm localhost 1186
Additional information about using ndb_mgm can be found in Section 16.5.5.4, “Command Options for ndb_mgm” and Section 16.6.2, “Commands in the Management Client”.
All MySQL Cluster executables (except for
mysqld) take the following options. Users of
earlier MySQL Cluster versions should note that some of these
switches have been changed from those in MySQL 4.1 Cluster in
order to make them consistent with one another as well as with
mysqld. You can use the -?
switch to view a list of supported options.
-?
, --usage
,
--help
Prints a short list with descriptions of the available command options.
-V
, --version
Prints the version number of the ndbd
process. The version number is the MySQL Cluster version
number. The version number is relevant because not all
versions can be used together, and at startup the MySQL
Cluster processes verifies that the versions of the binaries
being used can co-exist in the same cluster. This is also
important when performing an online software upgrade of
MySQL Cluster (see Software Upgrade of MySQL
Cluster
).
-c
,
connect_string
--connect-string
connect_string
sets the connect
string to the management server as a command option.
shell> ndbd --connect-string="nodeid=2;host=ndb_mgmd.mysql.com:1186"
--debug[=
options
]
This option can only be used for versions compiled with debugging enabled. It is used to enable output from debug calls in the same manner as for the mysqld process.
-e
, --execute
Can be used to send a command to a Cluster executable from the system shell. For example, either of the following:
shell> ndb_mgm -e show
or
shell> ndb_mgm --execute="SHOW"
is equivalent to
NDB> SHOW;
This is analogous to how the -e
option
works with the mysql command-line client.
See Section 4.3.1, “Using Options on the Command Line”.
--ndbcluster
If the binary includes support for the NDB
Cluster
storage engine, the default disabling of
the NDB Cluster
storage engine (also
referred to more simply as the NDB
storage engine) can be overridden by using this option.
The NDB Cluster
storage engine is
necessary for using MySQL Cluster.
--skip-ndbcluster
Disables the NDB Cluster
storage
engine. This option is activated by default for binaries
where it is included; in other words, the NDB
Cluster
storage engine is disabled until
activated via --ndbcluster
. This option
applies only if the server was compiled with support for
the NDB Cluster
storage engine.
--ndb-connectstring=
connect_string
When using the NDB
storage engine, it
is possible through setting this option to specify the
management server that distributes cluster configuration
data.
For some common options see Section 16.5.5, “Command Options for MySQL Cluster Processes”.
-d
, --daemon
Instructs ndbd to execute as a daemon process. In MySQL 5.0, this is the default behavior.
--nodaemon
Instructs ndbd not to start as a daemon process. Useful when ndbd is being debugged and you want output to be redirected to the screen.
--initial
Instructs ndbd to perform an initial start. An initial start erases any files created for recovery purposes by earlier instances of ndbd. It also re-creates recovery log files. Note that on some operating systems this process can take a substantial amount of time.
An --initial
start is to be used only the
very first time that the ndbd process
is started, as it removes all files from the Cluster
filesystem and re-creates all REDO log files. The
exceptions to this rule are:
When performing a software upgrade which has changed the contents of any files.
When restarting the node with a new version of ndbd.
As a measure of last resort when for some reason the node restart or system restart repeatedly fails. In this case be aware that that this node can no longer be used to restore data due to the destruction of the datafiles.
This option does not affect any backup files that have already been created by the affected node.
--nostart
Instructs ndbd not to start automatically. When this option is used, ndbd connects to the management server, obtains configuration data from it, and initialises communication objects. However, it will not actually start the execution engine until specifically requested to do so by the management server. This can be accomplished by issuing the proper command to the management client.
For some common options see Section 16.5.5, “Command Options for MySQL Cluster Processes”.
-f
,
(OBSOLETE): filename
,
--config-file=filename
-c
filename
Instructs the management server as to which file it should
use for its configuration file. This option must be
specified. The file name defaults to
config.ini
.
Note: The
-c
shortcut is obsolete in MySQL
5.0 Cluster and should not be used in new
installations.
-d
, --daemon
Instructs ndb_mgmd to start as a daemon. This is the default behavior.
--nodaemon
Instructs the management server not to start as a daemon.
For some common options see Section 16.5.5, “Command Options for MySQL Cluster Processes”.
[
host_name
[port_num
]]
To start the management client it is necessary to specify
where the management server resides, which means
specifying the hostname and the port. The default hostname
is localhost
; the default port is 1186.
--try-reconnect=
number
If the connection to the management server is broken, then
the node tries to reconnect to it every 5 seconds until it
succeeds. By using this option, it is possible to limit
the number of attempts to
number
before giving up and
reporting an error instead.
Managing a MySQL Cluster involves a number of tasks, the first of which is to configure and start MySQL Cluster. This is covered in Section 16.4, “MySQL Cluster Configuration” and Section 16.5, “Process Management in MySQL Cluster”.
The following sections cover the management of a running MySQL Cluster.
There are essentially two methods of actively managing a running
MySQL Cluster. The first of these is through the use of commands
entered into the management client whereby cluster status can be
checked, log levels changed, backups started and stopped and nodes
stopped and started. The second method involves studying the
contents of the cluster log
ndb_
in the management server's node_id
_cluster.logDataDir
directory.
(Recall that node_id
represents the
unique identifier of the node whose activity is being logged.) The
cluster log contains event reports generated by
ndbd. It is also possible to send cluster log
entries to a Unix system log.
This section describes the steps involved when the cluster is started.
There are several different startup types and modes, as shown here:
Initial Start: The
cluster starts with a clean filesystem on all data nodes.
This occurs either when the cluster started for the very
first time, or when it is restarted using the
--initial
option.
System Restart: The cluster starts and reads data stored in the data nodes. This occurs when the cluster has been shut down after having been in use, when it is desired for the cluster resume operations from the point where it left off.
Node Restart: This is the online restart of a cluster node while the cluster itself is running.
Initial Node Restart: This is the same as a node restart, except that the node is reinitialised and started with a clean filesystem.
Prior to startup, each data node (ndbd
process) must be initialised. This consists of the following:
Obtain a Node ID.
Fetch configuration data.
Allocate ports to be used for inter-node communications.
Allocate memory according to settings obtained from the cofiguration file.
Once each data node has been initialised, the cluster startup process can proceed. The stages which the cluster goes through during this process are listed here:
Stage 0
Clear the cluster filesystem. This occurs
only if the cluster was started with
the --initial
option.
Stage 1
Cluster connections are set up; inter-node communications are established. Cluster heartbeats are started.
Stage 2
The arbitrator node is elected.
If this is a system restart, then the cluster determines the latest restorable global checkpoint.
Stage 3
This stage consists of the initialisation of a number of internal cluster variables.
Stage 4
For an initial start or initial node restart, the redo log
files are created. The number of these files is equal to
NoOfFragmentLogFiles
.
For a system restart:
Read schema(s).
Read data from the local checkpoint and undo logs.
Apply all redo information until the latest restorable global checkpoint has been reached.
For a node restart, find the tail of the redo log.
Stage 5
If this is an initial start, create the
SYSTAB_0
and
NDB$EVENTS
internal system tables.
For a node restart or an initial node restart:
The node is included in transaction handling operations.
The node's schema is compared with the master' and synchronised with it.
Synchronise data received in the form of
INSERT
from the other data nodes
in this node's node group.
In all cases, wait for complete local checkpoint as determined by the arbitrator.
Stage 6
Update internal variables.
Stage 7
Update internal variables.
Stage 8
In a system restart, rebuild all indexes.
Stage 9
Update internal variables.
Stage 10
At this point in a node restart or initial node restart, APIs may connect to the node and being to receive events.
Stage 11
At this point in a node restart or initial node restart, event delivery is handed over to the node joining the cluster. The newly-joined node takes over responsibility for delivering its primary data to subscribers.
Once this process is completed for an initial start or system restart, handling of transactions is enabled. For a node restart or initial node restart, completion of the startup process means that the node may now act as a transaction co-ordinator.
In addition to the central configuration file, a cluster may also be controlled through a command line interface available through the management client ndb_mgm. This is the primary administrative interface to a running cluster.
The management client has the following basic commands. In the
listing that follows, node_id
denotes
either a database node ID or the keyword ALL
,
which indicates that the command should be applied to all of the
cluster's data nodes.
HELP
Displays information on all available commands.
SHOW
Displays information on the cluster's status.
Note: In a cluster where multiple management nodes are in use, this command displays information only for data nodes that are actually connected to the current management server.
node_id
START
Starts the data node identified by
node_id
(or all data nodes).
node_id
STOP
Stops the data node identified by
node_id
(or all data nodes).
node_id
RESTART [-N]
[-I]
Restarts the data node identified by
node_id
(or all data nodes).
node_id
STATUS
Displays status information for the data node identified by
node_id
(or for all data nodes).
ENTER SINGLE USER MODE
node_id
Enters single-user mode, whereby only the MySQL server
identified by the node ID node_id
is allowed to access the database.
EXIT SINGLE USER MODE
Exists single user mode allowing all SQL nodes (that is, all running mysqld processes) to access the database.
QUIT
Terminates the management client.
SHUTDOWN
Shuts down all cluster nodes, except for SQL nodes, and exits.
Commands for the event logs are given in the next section; commands for creating backups and restoring from backup are provided in a separate section on these topics.
In this section, we discuss the types of event logs provided by MySQL Cluster, and the types of events that are logged.
MySQL Cluster provides two types of event log. These are the cluster log, which includes events generated by all cluster nodes, and node logs, which are local to each data node.
Output generated by cluster event logging can have multiple
destinations including a file, the management server console
window, or syslog
. Output generated by node
event logging is written to the data node's console window.
Both sorts of event logs can be set to log different subsets of events.
Note: The cluster log is the log recommended for most uses, since it provides logging information for an entire cluster in a single file. Node logs are intended to be used only during application development, or for debugging application code.
Each reportable event can be distinguished according to three different criteria:
Category: This can be any one of the
following values: STARTUP
,
SHUTDOWN
, STATISTICS
,
CHECKPOINT
,
NODERESTART
,
CONNECTION
, ERROR
, or
INFO
.
Priority: This is represented by one of the numbers from 1 to 15 inclusive, where 1 indicates “most important” and 15 “least important”.
Severity Level: This can be any one of
the following values: ALERT
,
CRITICAL
, ERROR
,
WARNING
, INFO
, or
DEBUG
.
Both the cluster log and the node log can be filtered on these properties.
The following management commands are related to the cluster log:
CLUSTERLOG ON
Turn cluster log on.
CLUSTERLOG OFF
Turn cluster log off.
CLUSTERLOG INFO
Information about cluster log settings.
node_id
CLUSTERLOG
category
=threshold
Logs category
events with
priority less than or equal to
threshold
in the cluster log.
CLUSTERLOG FILTER
severity_level
Toggles cluster logging of events of the specified
severity_level
.
The following table describes the default setting (for all data nodes) of the cluster log category threshold. If an event has a priority with a value lower than or equal to the priority threshold, then it is reported in the cluster log.
Note that events are reported per data node, and that the threshold can be set to different values on different nodes.
Category | Default threshold (All data nodes) |
STARTUP | 7 |
SHUTDOWN | 7 |
STATISTICS | 7 |
CHECKPOINT | 7 |
NODERESTART | 7 |
CONNECTION | 7 |
ERROR | 15 |
INFO | 7 |
Thresholds are used to filter events within each category. For
example, a STARTUP
event with a priority of
3 is not logged unless the threshold for
STARTUP
is changed to 3 or lower. Only
events with priority 3 or lower are sent if the threshold is
3.
Event severity levels are shown below.
(Note: These correspond to
Unix syslog
levels, except for
LOG_EMERG
and
LOG_NOTICE
, which are not used or mapped.)
1 | ALERT | A condition that should be corrected immediately, such as a corrupted system database |
2 | CRITICAL | Critical conditions, such as device errors or insufficient resources |
3 | ERROR | Conditions that should be corrected, such as configuration errors |
4 | WARNING | Conditions that are not errors, but that might require special handling |
5 | INFO | Informational messages |
6 | DEBUG | Debugging messages used for NDB Cluster development |
Event severity levels can be turned on or off. If a severity level is turned on, then all events with a priority less than or equal to the category thresholds are logged. If the severity level is turned off then no events belonging to that severity level are logged.
An event report as reported in the event logs has the
following format:
. For example:
datetime
[string
]
severity
--
message
09:19:30 2005-07-24 [NDB] INFO -- Node 4 Start phase 4 completed
All reportable events are discussed in this section, ordered by category and severity level within each category.
CONNECTION
Events
These are events associated with connections between Cluster nodes.
Event | Priority | Severity Level | Description |
DB nodes connected | 8 | INFO | Data nodes connected |
DB nodes disconnected | 8 | INFO | Data nodes disconnected |
Communication closed | 8 | INFO | SQL node or data node connection closed |
Communication opened | 8 | INFO | SQL node or data node connection opened |
CHECKPOINT
Events
The logging messages shown below are assocated with checkpoints.
(Note: GCP = Global Checkpoint, LCP = Local Checkpoint.)
Event | Priority | Severity Level | Description |
LCP stopped in calc keep GCI | 0 | ALERT | LCP stopped |
Local checkpoint fragment completed | 11 | INFO | LCP on a fragment has been completed |
Global checkpoint completed | 10 | INFO | GCP finished |
Global checkpoint started | 9 | INFO | Start of GCP: REDO log is written to disk |
Local checkpoint completed | 8 | INFO | LCP completed normally |
Local checkpoint started | 7 | INFO | Start of LCP: data written to disk |
Report undo log blocked | 7 | INFO | UNDO logging blocked; buffer near overflow |
STARTUP
Events
The following events are generated in response to the startup of a node or of the cluster and of its success or failure. They also provide information relating to the progress of the startup process, including information concerning logging activities.
Event | Priority | Severity Level | Description |
Internal start signal received STTORRY | 15 | INFO | Blocks received after completion of restart |
Undo records executed | 15 | INFO | |
New REDO log started | 10 | INFO | GCI keep X , newest restorable GCI
Y |
New log started | 10 | INFO | Log part X , start MB
Y , stop MB
Z |
Node has been refused for inclusion in the cluster | 8 | INFO | Node cannot be included in cluster due to misconfiguration, inability to establish communication, or other problem |
DB node neighbours | 8 | INFO | Shows neighbouring data nodes |
DB node start phase X completed | 4 | INFO | A data node start phase has been completed |
Node has been successfully included into the cluster | 3 | INFO | Displays the node, managing node, and dynamic ID |
DB node start phases initiated | 1 | INFO | NDB Cluster nodes starting |
DB node all start phases completed | 1 | INFO | NDB Cluster nodes started |
DB node shutdown initiated | 1 | INFO | Shutdown of data node has commenced |
DB node shutdown aborted | 1 | INFO | Unable to shut down data node normally |
NODERESTART
Events
The following events are generated when restarting a node and relate to the success or failure of the node restart process.
Event | Priority | Severity Level | Description |
Node failure phase completed | 8 | ALERT | Reports completion of node failure phases |
Node has failed, node state was X | 8 | ALERT | Reports that a node has failed |
Report arbitrator results | 2 | ALERT | There are 8 different possible results for arbitration attempts:
|
Completed copying a fragment | 10 | INFO | |
Completed copying of dictionary information | 8 | INFO | |
Completed copying distribution information | 8 | INFO | |
Starting to copy fragments | 8 | INFO | |
Completed copying all fragments | 8 | INFO | |
GCP takeover started | 7 | INFO | |
GCP takeover completed | 7 | INFO | |
LCP takeover started | 7 | INFO | |
LCP takeover completed (state = X ) | 7 | INFO | |
Report whether an arbitrator is found or not | 6 | INFO | There are 7 different possible outcomes when seeking an arbitrator:
|
STATISTICS
Events
The following events are of a statistical nature. They provide information such as numbers of transactions and other operations, amount of data sent or received by individual nodes, and memory usage.
Event | Priority | Severity Level | Description |
Report job scheduling statistics | 9 | INFO | Mean internal job scheduling statistics |
Sent number of bytes | 9 | INFO | Mean number of bytes sent to node X |
Received # of bytes | 9 | INFO | Mean number of bytes received from node X |
Report transaction statistics | 8 | INFO | Numbers of: transactions, commits, reads, simple reads, writes, concurrent operations, attribute info, and aborts |
Report operations | 8 | INFO | Number of operations |
Report table create | 7 | INFO | |
Memory usage | 5 | INFO | Data and index memory usage (80%, 90%, and 100%) |
ERROR
Events
These events relate to Cluster errors and warnings; the presence of one or more of these generally indicates that a major malfunction or failure has occurred.
Event | Priority | Severity | Description |
Dead due to missed heartbeat | 8 | ALERT | Node X declared “dead” due to
missed heartbeat |
Transporter errors | 2 | ERROR | |
Transporter warnings | 8 | WARNING | |
Missed heartbeats | 8 | WARNING | Node X missed heartbeat
#Y |
General warning events | 2 | WARNING |
INFO
Events
These events provide general information about the state of the cluster and activities associated with Cluster maintenance, such as logging and heartbeat transmission.
Event | Priority | Severity | Description |
Sent heartbeat | 12 | INFO | Heartbeat sent to node X |
Create log bytes | 11 | INFO | Log part, log file, MB |
General info events | 2 | INFO |
Single user mode allows the database administrator to restrict access to the database system to a single MySQL server (SQL node). When entering single user mode all connections to all other MySQL servers are closed gracefully and all running transactions are aborted. No new transactions are allowed to be started.
Once the cluster has entered single user mode, only the designated SQL node is granted access to the database. You can use the ALL STATUS command to see when the cluster has entered single user mode.
Example:
NDB> ENTER SINGLE USER MODE 5
After this command has executed and the cluster has entered
single user mode, the SQL node whose node ID is
5
becomes the cluster's only permitted user.
The node specified in the command above must be a MySQL Server node; An attempt to specify any other type of node will be rejected.
Note: When the above commmand is invoked, all transactions running on the designated node are aborted, the connection is closed, and the server must be restarted.
The command EXIT SINGLE USER MODE changes the state of the cluster's data nodes from single user mode to normal mode. MySQL Servers waiting for a connection (that is, for the cluster to become ready and available), are now permitted to connect. The MySQL Server denoted as the single-user SQL node continues to run (if still connected) during and after the state change.
Example:
NDB> EXIT SINGLE USER MODE
The recommended way to handle a node failure when running in single user mode is to do either of the following:
Finish all single user mode transactions
Issue the EXIT SINGLE USER MODE command
Restart the cluster's data nodes
or
Restart database nodes prior to entering single user mode.
This section describes how to create a backup and how to restore the database from a backup at a later time.
A backup is a snapshot of the database at a given time. The backup consists of three main parts:
Metadata: the names and definitions of all database tables.
Table records: the data actually stored in the database tables at the time that the backup was made
Transaction log: a sequential record telling how and when data was stored in the database
Each of these is saved on all nodes participating in the backup. During backup each node saves these three parts into three files on disk:
BACKUP-
backup_id
.node_id
.ctl
A control file containing control information and metadata. Each node saves the same table definitions (for all tables in the cluster) to its own version of this file.
BACKUP-
backup_id
-0.node_id
.data
A data file containing the table records, which are saved on a per-fragment basis; that is, different nodes save different fragments during the backup. The file saved by each node starts with a header that states to which tables the records belong. Following the list of records there is a footer containing a checksum for all records.
BACKUP-
backup_id
.node_id
.log
A log file containing records of committed transactions. Only transactions on tables stored in the backup are stored in the log. Nodes involved in the backup save different records, since different nodes host different database fragments.
In the listing above, backup_id
stands for the backup identifier and
node_id
is the unique identifier
for the node creating the file.
Before starting a backup, make sure that the cluster is properly configured for performing one. (See Section 16.6.5.4, “Configuration for Cluster Backup”.)
To create a backup using the management server involves the following steps:
Start the management server (ndb_mgm).
Execute the command START BACKUP
.
The management server will reply with the message
Start of backup ordered
. This means
that the management server has submitted the request to
the cluster, but has not yet received any response.
The management server will reply Backup
,
where backup_id
startedbackup_id
is the unique
identifier for this particular backup. (This identifier
will also be saved in the cluster log, if it has not been
configured otherwise.) This means that the cluster has
received and processed the backup request. It does
not mean that the backup has been
completed.
The management server will signal that the backup is
finished with the message Backup
.
backup_id
completed
To abort a backup already in progress:
Start the management server.
Execute the command ABORT BACKUP
. The number
backup_id
backup_id
is the identifier of
the backup that was included in the response of the
management server when the backup was started (in the
message Backup
).
backup_id
started
The management server will acknowledge the abort request
with Abort of backup
;
note that no actual response to this request has yet been
received.
backup_id
ordered
Once the the backup has been aborted, the management
server will report Backup
. This
means that the cluster has terminated the backup and that
all files related to this backup have been removed from
the cluster filesystem.
backup_id
has been aborted for
reason XYZ
It is also possible to abort a backup in progress from the system shell using this command:
shell> ndb_mgm -e "ABORT BACKUP backup_id
"
Note: If there is no backup
with ID backup_id
running when it
is aborted, the management server does not make any exlicit
response. However, the fact that an invalid abort command was
sent is indicated in the cluster log.
The cluster restoration program is implemented as a separate command line utility ndb_restore, which reads the files created by the backup and inserts the stored information into the database. The restore program must be executed once for each set of backup files, that is, as many times as there were database nodes running when the backup was created.
The first time you run the restoration program, you also need
to restore the metadata; in other words, you must re-create
the database tables. (Note that the cluster should have an
empty database when starting to restore a backup.) The restore
program acts as an API to the cluster and therefore requires a
free connection in order to connect to the cluster. This can
be verified with the ndb_mgm command
SHOW (you can accomplish this from a system
shell using ndb_mgm -e SHOW). The switch
-c
may be used to locate the MGM node (see
Section 16.4.4.2, “The MySQL Cluster connectstring
connectstring
” for information
on connectstrings). The backup files must be present in the
directory given as an argument to the restoration program.
It is possible to restore a backup to a database with a
different configuration than it was created from. For example,
suppose that a backup with backup ID 12
,
created in a cluster with two database nodes having the node
IDs 2
and 3
, is to be
restored to a cluster with four nodes. Then
ndb_restore must be run twice — once
for each database node in the cluster where the backup was
taken.
Note: For rapid restoration, the data may be restored in parallel, provided that there is a sufficient number of cluster connections available. However, the data files must always be applied before the logs.
There are four configuration parameters essential for backup:
BackupDataBufferSize
Amount of memory used to buffer data before it is written to disk.
BackupLogBufferSize
Amount of memory used to buffer log records before these are written to disk.
BackupMemory
Total memory allocated in a database node for backups. This should be the sum of the memory allocated for the backup data buffer and the backup log buffer.
BackupWriteSize
Size of blocks written to disk. This applies for both the backup data buffer and the backup log buffer.
More detailed information about these parameters can be found in Section 16.4, “MySQL Cluster Configuration”.
If an error code is returned when issuing a backup request, the most likely cause is insufficient memory or insufficient disk space. You should check that there is enough memory allocated for the backup. Also check that there is enough space on the hard drive partition of the backup target.
In MySQL 5.0, NDB
does not
support repeatable reads, which can cause problems with the
restore process. While the backup process is
“hot”, restoring a MySQL Cluster from backup is
not a 100% “hot” process. This is due to the fact
that, for the duration of the restore process, running
transactions get non-repeatable reads from the restored data.
This means that the state of the data is inconsistent while
the restore is in progress.
Even before design of NDB Cluster
began in
1996, it was evident that one of the major problems to be
encountered in building parallel databases would be communication
between the nodes in the network. For this reason, NDB
Cluster
was designed from the very beginning to allow
for the use of a number of different data transport mechanisms. In
this Manual, we use the term transporter
for these.
Currently the MySQL Cluster codebase includes support for 4 different transporters. Most users today employ TCP/IP over Ethernet since it is ubiquitous. This is also by far the best-tested transporter in MySQL Cluster.
We are working to make sure that communication with the ndbd process is made in “chunks” that are as large as possible since this benefits all types of data transmission.
For users who desire it, it is also possible to use cluster interconnects to enhance performance even further. There are two ways to achieve this: either a custom transporter can be designed to handle this case, or one can use socket implementations that bypass the TCP/IP stack to one extent or another. We have experimented with both of these techniques using the SCI (Scalable Coherent Interface) technology developed by Dolphin.
In this section we will show how one can adapt a cluster configured for normal TCP/IP communication to use SCI Sockets instead. This documentation is based on SCI Sockets version 2.3.0 as of 01 October 2004.
Prerequisites
Any machines with which you wish to use SCI Sockets need to be equipped with SCI cards.
It is possible to use SCI Sockets with any version of MySQL Cluster. No special builds are needed since it uses normal socket calls which are already available in MySQL Cluster. However, SCI Sockets are currently supported only on the Linux 2.4 and 2.6 kernels. SCI Transporters have been tested successfully on additional operating systems although we have verified these only with Linux 2.4 to date.
There are essentially four requirements for SCI Sockets:
Building the SCI Socket libraries.
Installation of the SCI Socket kernel libraries.
Installation of one or two configuration files.
The SCI Socket kernel library must enabled either for the entire machine or for the shell where the MySQL Cluster processes are started.
This process needs to be repeated for each machine in the cluster where you plan to use SCI Sockets for inter-node communication.
Two packages need to be retrieved to get SCI Sockets working:
The source code package containing the DIS support libraries for the SCI Sockets libraries.
The source code package for the SCI Socket libraries themselves.
Currently, these are available only in source code format. The
latest versions of these packages at the time of this writing
were available as (respectively)
DIS_GPL_2_5_0_SEP_10_2004.tar.gz
and
SCI_SOCKET_2_3_0_OKT_01_2004.tar.gz
. You
should be able to find these (or possibly newer versions) at
http://www.dolphinics.no/support/downloads.html.
Package Installation
Once you have obtained the library packages, the next step is to unpack them into appropriate directories, with the SCI Sockets library unpacked into a directory below the DIS code. Next, you need to build the libraries. This example shows the commands used on Linux/x86 to perform this task:
shell>tar xzf DIS_GPL_2_5_0_SEP_10_2004.tar.gz
shell>cd DIS_GPL_2_5_0_SEP_10_2004/src/
shell>tar xzf ../../SCI_SOCKET_2_3_0_OKT_01_2004.tar.gz
shell>cd ../adm/bin/Linux_pkgs
shell>./make_PSB_66_release
It is possible to build these libraries for some 64-bit procesors. To build the libraries for Opteron CPUs using the 64-bit extensions, run make_PSB_66_X86_64_release rather than make_PSB_66_release; if the build is made on an Itanium machine, then you should use make_PSB_66_IA64_release. The X86-64 variant should work for Intel EM64T architectures but this has not yet (to our knowledge) been tested.
Once the build process is complete, the compiled libraries will
be found in a zipped tar file with a name along the lines of
DIS-
.
It is now time to install the package in the proper place. In
this example we will place the installation in
<operating-system>
-time
-date
/opt/DIS
.
(Note: You will most likely
need to run the following as the system root user.)
shell>cp DIS_Linux_2.4.20-8_181004.tar.gz /opt/
shell>cd /opt
shell>tar xzf DIS_Linux_2.4.20-8_181004.tar.gz
shell>mv DIS_Linux_2.4.20-8_181004 DIS
Network Configuration
Now that all the libraries and binaries are in their proper place, we need to ensure that the SCI cards have proper node IDs within the SCI address space.
It is also necessary to decide on the network structure before proceeding. There are three types of network structures which can be used in this context:
A simple one-dimensional ring
One or more SCI switches with one ring per switch port
A two- or three-dimensional torus.
Each of these topologies has its own method for providing node IDs. We discuss each of them in brief.
A simple ring uses node IDs which are non-zero multiples of 4: 4, 8, 12,...
The next possibility uses SCI switches. An SCI switch has 8 ports, each of which can support a ring. It is necessary to make sure that that different rings use different node ID spaces. In a typical configuration, the first port uses node IDs below 64 (4 - 60), the next 64 node IDs (68 - 124) are assigned to the next port, and so on, with node IDs 452 - 508 being assigned to the eighth port.
Two- and three-dimensional torus network structures take into account where each node is located in each dimension, incrementing by 4 for each node in the first dimension, by 64 in the second dimension, and (where applicable) by 1024 in the third dimension. See Dolphin's Web site for more thorough documentation.
In our testing we have used switches, although most large cluster installations use 2- or 3-dimensional torus structures. The advantage provided by switches is that, with dual SCI cards and dual switches, it is possible to build with relative ease a redundant network where the average failover time on the SCI network is on the order of 100 microseconds. This is supported by the SCI transporter in MySQL Cluster and is also under development for the SCI Socket implementation.
Failover for the 2D/3D torus is also possible but requires sending out new routing indexes to all nodes. However, this requires only 100 milliseconds or so to complete and should be acceptable for most high-availability cases.
By placing cluster data nodes properly within the switched architecture, it is possible to use 2 switches to build a structure whereby 16 computers can be interconnected and no single failure can hinder more than one of them. With 32 computers and 2 switches it is possible to configure the cluster in such a manner that no single failure can cause the loss of more than two nodes; in this case it is also possible to know which pair of nodes is affected. Thus, by placing the two nodes in separate node groups, it is possible to build a “safe” MySQL Cluster installation.
To set the node ID for an SCI card use the following command in
the /opt/DIS/sbin
directory. In this
example -c 1
refers to the number of the SCI
card (this will always be 1 if there is only 1 card in the
machine), -a 0
refers to adapter 0; and
68
is the node ID:
shell> ./sciconfig -c 1 -a 0 -n 68
If you have multiple SCI cards in the same machine, you can
determine which card has which slot by issuing the following
command (again we assume that the current working directory is
/opt/DIS/sbin
):
shell> ./sciconfig -c 1 -gsn
This will give you the SCI card's serial number. Then repeat
this procedure with -c 2
, and so on, for each
card in the machine. Once you have matched each card with a
slot, you can set node IDs for all cards.
After the necessary libraries and binaries are installed, and
the SCI node IDs are set, the next step is to set up the mapping
from hostnames (or IP addresses) to SCI node IDs. This is done
in the SCI sockets configuration file, which should be saved as
/etc/sci/scisock.conf
. In this file, each
SCI node ID is mapped through the proper SCI card to the
hostname or IP address that it is to communicate with. Here is a
very simple example of such a configuration file:
#host #nodeId alpha 8 beta 12 192.168.10.20 16
It is also possible to limit the configuration so that it
applies only to a subset of the available ports for these hosts.
An additional configuration file
/etc/sci/scisock_opt.conf
can be used to
accomplish this, as shown here:
#-key -type -values EnablePortsByDefault yes EnablePort tcp 2200 DisablePort tcp 2201 EnablePortRange tcp 2202 2219 DisablePortRange tcp 2220 2231
Driver Installation
With the configuration files in place, the drivers can be installed.
First, the low-level drivers and then the SCI socket driver need to be installed:
shell>cd DIS/sbin/
shell>./drv-install add PSB66
shell>./scisocket-install add
If desired, the installation can be checked by invoking a script which verifies that all nodes in the SCI socket configuration files are accessible:
shell>cd /opt/DIS/sbin/
shell>./status.sh
If you discover an error and need to change the SCI socket configuration, it is necessary to use the ksocketconfig to accomplish this task:
shell>cd /opt/DIS/util
shell>./ksocketconfig -f
Testing the Setup
To ensure that SCI sockets are actually being used, you can
employ the latency_bench test program. Using
this utility's server component, clients can connect to the
server in order to test the latency of the connection;
determining whether or not SCI is enabled should be fairly
simple from observing the latency.
(Note: Before using
latency_bench, it is necessaryto set the
LD_PRELOAD
environment variable as shown
later in this section.)
To set up a server, use the following:
shell>cd /opt/DIS/bin/socket
shell>./latency_bench -server
To run a client, use latency_bench again,
except this time with the -client
option:
shell>cd /opt/DIS/bin/socket
shell>./latency_bench -client
server_hostname
SCI socket configuration should now be complete and MySQL Cluster ready to use both SCI Sockets and the SCI transporter (see Section 16.4.4.10, “MySQL Cluster SCI Transport Connections”).
Starting the Cluster
The next step in the process is to start MySQL Cluster. To
enable usage of SCI Sockets it is necessary to set the
environment variable LD_PRELOAD
before
starting ndbd, mysqld, and
ndb_mgmd. This variable should point to the
kernel library for SCI Sockets.
To start ndbd in a bash shell, do the following:
bash-shell> export LD_PRELOAD=/opt/DIS/lib/libkscisock.so bash-shell> ndbd
In a tcsh environment the same thing can be accomplished with:
tcsh-shell> setenv LD_PRELOAD=/opt/DIS/lib/libkscisock.so tcsh-shell> ndbd
Note: MySQL Cluster can use only the kernel variant of SCI Sockets.
The ndbd process has a number of simple constructs which are used to access the data in a MySQL Cluster. We have created a very simple benchmark to check the performance of each of these and the effects which various interconnects have on their performance.
There are four access methods:
Primary key access
This is the simple access of a record through its primary key. In the simplest case only one record is accessed at a time, which means that the full cost of setting up a number of TCP/IP messages and a number of costs for context switching are borne by this single request. In the case where multiple primary key accesses are sent in one batch then those accesses will share the cost of setting up the necessary TCP/IP messages and context switches. If the TCP/IP messages are for different destinations, then additional TCP/IP messages need to be set up.
Unique key access
Unique key accesses are similar to primary key accesses, except that a unique key access is executed as a read on an index table followed by a primary key access on the table. However, only one request is sent from the MySQL Server, and the read of the index table is handled by ndbd. Such requests also benefit from batching.
Full table scan
When no indexes exist for a lookup on a table, then a full scan of a table is performed. This is sent as a single request to the ndbd process, which then divides the table scan into a set of parallel scans on all cluster ndbd processes. In future versions of MySQL Cluster, an SQL node will be able to filter some of these scans.
Range scan using ordered index
When an ordered index is used, it performs a scan in the same manner as the full table scan, except that it scans only those records which are in the range used by the query transmitted by the MySQL server (SQL node). In MySQL 5.0 Cluster, all partitions are scanned in parallel when all bound index attributes include all attributes in the partitioning key.
To check the base performance of these access methods we have developed a set of benchmarks. One such benchmark, testReadPerf, tests simple and batched primary and unique key accesses. This benchmark also measures the setup cost of range scans by issuing scans returning a single record. There is also a variant of this benchmark which uses a range scan to fetch a batch of records.
In this way, we can determine the cost of both a single key access and a single record scan access, as well as measure the impact of the communication media used, on base access methods.
In our tests, we ran the base benchmarks for both a normal transporter using TCP/IP sockets and a similar setup using SCI sockets. The figures reported below are for small accesses of 20 records per access. The difference between serial and batched access decreases by a factor of 3 to 4 when using 2 kB records instead. SCI Sockets were not tested with 2 kB records. Tests were performed on a cluster with 2 data nodes running on 2 dual-CPU machines equipped with AMD MP1900+ processors.
Access type: TCP/IP sockets SCI Socket Serial pk access: 400 microseconds 160 microseconds Batched pk access: 28 microseconds 22 microseconds Serial uk access: 500 microseconds 250 microseconds Batched uk access: 70 microseconds 36 microseconds Indexed eq-bound: 1250 microseconds 750 microseconds Index range: 24 microseconds 12 microseconds
We also performed another set of tests to check the performance of SCI Sockets vis-à-vis that of the SCI transporter, and both of these as compared with the TCP/IP transporter. All these tests used primary key accesses either serially and multi-threaded, or multi-threaded and batched.
The tests showed that SCI sockets were about 100% faster than TCP/IP. The SCI transporter was faster in most cases compared to SCI sockets. One notable case occurred with many threads in the test program, which showed that the SCI transporter did not perform very well when used for the mysqld process.
Our overall conclusion was that, for most benchmarks, using SCI sockets improves performance by approximately 100% over TCP/IP, except in rare instances when communication performance is not an issue. This can occur when scan filters make up most of processing time or when very large batches of primary key accesses are achieved. In that case the CPU processing in the ndbd processes becomes a fairly large part of the overhead.
Using the SCI transporter instead of SCI Sockets is only of interest in communicating between ndbd processes. Using the SCI transporter is also only of interest if a CPU can be dedicated to the ndbd process since the SCI transporter ensures that this process will never go to sleep. It is also important to ensure that the ndbd process priority is set in such a way that the process does not lose priority due to running for an extended period of time, as can be done by locking processes to CPUs in Linux 2.6. If such a configuration is possible, then the ndbd process will benefit by 10-70% as compared with using SCI sockets. (The larger figures will be seen when performing updates and probably on parallel scan operations as well.)
There are several other optimized socket implementations for computer clusters, including Myrinet, Gigabit Ethernet, Infiniband and the VIA interface. We have tested MySQL Cluster so far only with SCI sockets. We also include documentation above on how to set up SCI sockets using ordinary TCP/IP for MySQL Cluster.
In this section, we provide a listing of known limitations in MySQL Cluster releases in the 5.0.x series when compared to features available when using the MyISAM and InnoDB storage engines. Currently there are no plans to address these in coming releases of MySQL 5.0; however, we will attempt to supply fixes for these issues in subsequent release series. If you check the “Cluster” category in the MySQL bugs database at http://bugs.mysql.com, you can find known bugs which (if marked “5.0”) we intend to correct in upcoming releases of MySQL 5.0.
(Note: See the end of this section for a list of issues in MySQL 4.1's Cluster implementation that have been resolved in the current version.)
Noncompliance in syntax (resulting in errors when running existing applications):
Text indexes are not supported.
Geometry datatypes (WKT
and
WKB
) are not supported.
Non-compliance in limits or behavior (may result in errors when running existing applications):
There is no partial rollback of transactions. A duplicate key or similar error will result in a rollback of the entire transaction.
A number of hard limits exist which are configurable, but available main memory in the cluster sets limits. See the complete list of configuration parameters in Section 16.4.4, “Configuration File”. Most configuration parameters can be upgraded online. These hard limits include:
Database memory size and index memory size
(DataMemory
and
IndexMemory
, repectively).
The maximum number of transactions that can be
performed is set using the configuration parameter
MaxNoOfConcurrentOperations
. Note
that bulk loading, TRUNCATE TABLE
,
and ALTER TABLE
are handled as
special cases by running multiple transactions, and so
are not subject to this limitation.
Different limits related to tables and indexes. For
example, the maximum number of ordered indexes per
table is determined by
MaxNoOfOrderedIndexes
.
Database names, table names and attribute names cannot be
as long in NDB
tables as with other
table handlers. Attribute names are truncated to 31
characters, and if not unique after truncation give rise
to errors. Database names and table names can total a
maximum of 122 characters. (That is, the maximum length
for an NDB Cluster
table name is 122
characters less the number of characters in the name of
the database of which that table is a part.)
In MySQL 5.0, all Cluster table rows are of
fixed length. This means (for example) that if a table has
one or more VARCHAR
fields containing
only relatively small values, more memory and disk space
is required when using the NDB
storage
engine than would be for the same table and data using the
MyISAM
engine. (In other words, in the
case of a VARCHAR
column, the column
requires the same amount of storage as a
CHAR
column of the same size.)
The maximum number of tables in a Cluster database is limited to 1792.
The maximum number of attributes per table is limited to 128.
The maximum permitted size of any one row is 8k,
not including data stored in
BLOB
columns.
The maximum number of attributes per key is 32.
Unsupported features (do not cause errors, but are not supported or enforced):
The foreign key construct is ignored, just as it is in
MyISAM
tables.
Savepoints and rollbacks to savepoints are ignored as in
MyISAM
.
Performance and limitation-related issues:
There are query performance issues due to sequential
access to the NDB
storage engine; it is
also relatively more expensive to do many range scans than
it is with either MyISAM
or
InnoDB
.
The Records in range
statistic is not
supported, resulting in non-optimal query plans in some
cases. Employ USE INDEX
or
FORCE INDEX
as a workaround.
Unique hash indexes created with USING
HASH
cannot be used for accessing a table if
NULL
is given as part of the key.
MySQL Cluster does not support durable commits on disk. Commits are replicated, but there is no guarantee that logs are flushed to disk on commit.
Missing features:
The only supported isolation level is
READ_COMMITTED
. (InnoDB supports
READ_COMMITTED
,
READ_COMMITTED
,
REPEATABLE_READ
, and
SERIALIZABLE
.) See
Section 16.6.5.5, “Backup Troubleshooting” for
information on how this can effect backup and restore of
Cluster databases.
No durable commits on disk. Commits are replicated, but there is no guarantee that logs are flushed to disk on commit.
Problems relating to multiple MySQL
servers (not relating to MyISAM
or InnoDB
):
ALTER TABLE
is not fully locking when
running multiple MySQL servers (no distributed table
lock).
MySQL replication will not work correctly off if updates are done on multiple MySQL servers. However, if the database partitioning scheme done at the application level, and no transactions take place across these partitions, then replication can be made to work.
Autodiscovery of databases is not supported for multiple
MySQL servers accessing the same MySQL Cluster. However,
autodiscovery of tables is supported in such cases. What
this means is that after a database named
db_name
is created or imported
using one MySQL server, you should issue a CREATE
DATABASE
statement on each additional MySQL server that access the
same MySQL Cluster. (As of MySQL 5.0.2 you may also use
db_name
;CREATE SCHEMA
.) Once this
has been done for a given MySQL server, that server should
be able to detect the database tables without error.
db_name
;
Issues exclusive to MySQL
Cluster (not related to MyISAM
or InnoDB
):
All machines used in the cluster must have the same architecture; that is, all machines hosting nodes must be either big-endian or little-endian, and you cannot use a mixture of both. For example, you cannot have a management node running on a PPC which directs a data node that is running on an x86 machine. This restriction does not apply to machines simply running mysql or other clients that may be accessing the cluster's SQL nodes.
It is not possible to make online schema changes such as
those accomplished using ALTER TABLE
or
CREATE INDEX
, as the NDB
Cluster
does not support autodiscovery of such
changes. (However, you can import or create a table that
uses a different storage engine, then convert it to
NDB
using ALTER TABLE
. In such a case, you need to
issue a tbl_name
ENGINE=NDBCLUSTER;FLUSH TABLES
command in order
to force the cluster to pick up the change.)
Online adding or dropping of nodes is not possible (the cluster must be restarted in such cases).
When using multiple management servers:
You must give nodes explicit IDs in connectstrings since automatic allocation of node IDs does not work across multiple management servers.
You must take extreme care to have the same configurations for all management servers. No special checks for this are performed by the cluster.
In order that management nodes be able to see one another, you must restart all data nodes after bringing up the cluster. (See Bug #13070 for a detailed explanation.)
Multiple network interfaces for data nodes are not supported. Use of these is liable to cause problems because, in the event of a data node failure, an SQL node waits for confirmation that the data node went down but never receives it since another route to that data node remains open. This can effectively make the cluster inoperable.
The maximum number of data nodes is 48.
The total maximum number of nodes in a MySQL Cluster is 63. This number includes all MySQL Servers (SQL nodes), data nodes, and management servers.
The above listing is intended to be complete with respect to the conditions set forth at the beginning of this section. You can report any discrepancies that you encounter to the MySQL bugs database at http://bugs.mysql.com/. If we do not plan to fix the problem in MySQL 5.0, we will add it to the list.
The following Cluster issues in MySQL 4.1 have been resolved in MySQL 5.0 as shown below:
The NDB Cluster
storage engine supports all
character sets and collations available in MySQL
5.0.
Cluster in MySQL 5.0 supports column indexes that make use of prefixes.
Unlike the case in MySQL 4.1, the Cluster storage engine in MySQL 5.0 supports MySQL' query cache. See Section 5.13, “The MySQL Query Cache”.
In this section, we discuss changes in the implementation of MySQL Cluster in MySQL 5.0 as compared to MySQL 4.1. We will also discuss our roadmap for further improvements to MySQL Cluster as currently planned for MySQL 5.1.
In the past we have recommended that users of MySQL Cluster not use version 5.0 of MySQL since MySQL Cluster in the 5.0.x series wasn't yet fully tested. Beginning with the release of MySQL 5.0.3-beta the clustering functionality of MySQL 5.0 became comparable to that of MySQL 4.1. MySQL 4.1 is still recommended for production use at this time; however, MySQL 5.0 is of high quality as well, and we encourage you to begin testing with Cluster in MySQL 5.0 if you think that you are interested in using it once it enters production later in 2005. There are relatively few changes between the NDB Cluster storage engine implementations in MySQL 4.1 and in 5.0, so the upgrade path should be relatively quick and painless.
Since MySQL 5.0.3-beta was made available, nearly all significantly new features being developed for MySQL Cluster are going into the MySQL 5.1 tree. We also provide some hints about what Cluster in MySQL 5.1 is likely to include later in this section (see Section 16.9.2, “MySQL 5.1 Development Roadmap for MySQL Cluster”).
MySQL 5.0.3-beta and later releases contain a number of new features that are likely to be of interest:
Push-Down Conditions: A query such as
SELECT * FROM t1 WHERE non_indexed_attribute = 1;
will use a full table scan and the condition will be
evaluated in the cluster's data nodes. Thus it is not
necessary to send the records across the network for
evaluation. (That is, function transport is used, rather
than data transport.) For this type of query you should see
a speed up factor of 5-10. Please note that this feature is
currently disabled by default (pending more thorough
testing), but it should work in most cases. This feature can
be enabled through the use of the command SET
engine-condition-pushdown=On;
command.
Alternatively, you can run mysqld with
the this feature enabled by starting the MySQL server with
the new --engine-condition-pushdown
option
flag.
You can use EXPLAIN
to determine when
push-down conditions are being used.
A major benefit of this change is that queries are now executed in parallel. This means that queries against non-indexed columns can run as much as 5 to 10 times, times the number of data nodes, faster than previously, since multiple CPUs can work on the query in parallel.
Decreased
IndexMemory
Usage: In MySQL
5.0, each record consumes approximately 25
bytes of index memory, and every unique index uses 25 bytes
per record of index memory (in addition to some data memory
since these are stored in a separate table). This is because
there is no storage of the primary key in the index memory
anymore.
Query Cache Enabled for MySQL Cluster: See Section 5.13, “The MySQL Query Cache” for information on configuring ans using the query cache.
New Optimizations: One optimization that merits particular attention is that a batched read interface is now used in some queries. For example, consider the following query:
SELECT * FROM t1 WHERE primary_key
IN (1,2,3,4,5,6,7,8,9,10);
This query will be executed 2 to 3 times more quickly than in previous MySQL Cluster versions due to the fact that all 10 key lookups are sent in a single batch rather than one at a time.
Limit On Number of Metadata Objects: In MySQL 4.1, each Cluster database may contain a maximum of 1600 metadataobjects, including database tables, system tables, indexes and BLOBs. In MySQL 5.0, we expect to increase this number to 20,320. We hope to implement this enhancement in the MySQL 5.0.6 beta release in mid-2005.
What is said here is a status report based on recent commits to the MySQL 5.1 source tree. It should be noted all 5.1 development is subject to change.
There are currently 4 major new features being developed for MySQL 5.1:
Integration of MySQL Cluster into MySQL Replication: This will make it possible to update from any MySQL Server in the cluster and still have the MySQL Replication handled by one of the MySQL Servers in the cluster and the installation on the slave side consistent.
Support for disk-based records: Records on disk will be supported. Indexed fields including the primary key hash index must still be stored in RAM but all other fields can be on disk.
Variable sized records: A
column defined as VARCHAR(255)
currently
uses 260 bytes of storage independent of what is stored in
any particular record. In MySQL 5.1 Cluster tables only the
portion of the field actually taken up by the record will be
stored. This will make possible a reduction in space
requirements for such columns by a factor of 5 in many
cases.
User-defined Partitioning:
Users will be able to define partitions based on the fields
part of the primary key. The MySQL Server will be able to
discover whether it is possible to prune away some of the
partitions from the WHERE
clause.
Partitioning based on KEY
,
HASH
, RANGE
, and
LIST
handlers will be possible, as well
as subpartitioning. This feature should also be available
for many other handlers.
In addition, we are working to increase the 8k size limit for rows containing columns of types other than BLOB or TEXT in Cluster tables. This is due to the fact that rows are currently fixed in size and the page size is 32,768 bytes (minus 128 bytes for the row header). Currently this means that if we allowed more than 8k per record, any remaining space (up to approximately 14,000 bytes) would be left empty. In MySQL 5.1, we plan to fix this limitation so that using more than 8k in a given row does not result in the remainder of the page being wasted.
What's the difference in using Cluster vs. using replication?
In a replication setup, a master MySQL server updates one or more slaves. Transactions are committed sequentially, and a slow transaction can cause the slave to lag behind the master. This means that if the master fails, it is possible that the slave might not have recorded the last few transactions. If a transaction-safe engine such as InnoDB is being used, then a transaction will either be complete on the slave or not applied at all, but replication does not guarantee that all data on the master and the slave will be consistent at all times. In MySQL Cluster, all data nodes are kept in synch, and a transaction committed by any one data node is committed for all data nodes. In the event of a data node failure, all remaining data nodes will remain in a consistent state.
In short, whereas standard MySQL replication is asynchronous, MySQL Cluster is synchronous.
We are planning to implement (asynchronous) replication for Cluster in MySQL 5.1. This will include the capability to replicate both between two clusters and between a MySQL cluster and a non-Cluster MySQL server.
Do I need to do any special networking to run Cluster? (How do computers in a cluster communicate?)
MySQL Cluster is intended to be used in a high-bandwidth environment, with computers connecting via TCP/IP. Its performance depends directly upon the connection speed between the cluster's computers. The minimum connectivity requirements for Cluster include a typical 100-megabit Ethernet network or the equivalent. We recommend you use gigabit Ethernet whenever available.
The faster SCI protocol is also supported, but requires special hardware. See Section 16.7, “Using High-Speed Interconnects with MySQL Cluster” for more information about SCI.
How many computers do I need to run a cluster, and why?
A minimum of three computers is required to run a viable cluster. However, the minimum recommended number of computers in a MySQL Cluster is four: one each to run the management and SQL nodes, and two computers to serve as storage nodes. The purpose of the two data nodes is to provide redundancy; the management node must run on a separate machine in order to guarantee continued arbitration services in the event that one of the data nodes fails.
What do the different computers do in a cluster?
A MySQL Cluster has both a physical and logical organization, with computers being the physical elements. The logical or functional elements of a cluster are referred to as nodes, and a computer housing a cluster node is sometimes referred to as a cluster host . Ideally, there will be one node per cluster host, although it is possible to run multiple nodes on a single host. There are three types of nodes, each corresponding to a specific role within the cluster. These are:
management node (MGM node): Provides management services for the cluster as a whole, including startup, shutdown, backups, and configuration data for the other nodes. The management node server is implemented as the application ndb_mgmd; the management client used to control MySQL Cluster via the MGM node is ndb_mgm.
data node: Stores and replicates data. Data node functionality is handled by an instance of the NDB data node process ndbd.
SQL node: This is simply an instance of MySQL Server (mysqld) started with the --ndb-cluster option.
With which operating systems can I use Cluster?
In MySQL 5.0, MySQL Cluster is officially supported on Linux, Mac OS X, and Solaris. We are working to add Cluster support for other platforms, including Windows, and our goal is eventually to offer MySQL Cluster on all platforms for which MySQL itself is supported.
It may be possible to run Cluster processes on other operating systems. We have had reports from users who say that they have run Cluster successfully on FreeBSD. However, Cluster on any but the three platforms mentioned here should be considered alpha software (at best), cannot be guaranteed relaiable in a production setting, and is not supported by MySQL AB.
What are the hardware requirements for running MySQL Cluster?
Cluster should run on any platform for which NDB-enabled binaries are available. Naturally, faster CPUs and more memory will improve performance, and 64-bit CPUs will likely be more effective than 32-bit processors. There must be sufficent memory on machines used for data nodes to hold each node's share of the database (see How much RAM do I Need? for more info). Nodes can communicate via a standard TCP/IP network and hardware. For SCI support, special networking hardware is required.
Since MySQL Cluster uses TCP/IP, does that mean I can run it over the Internet, with one or more nodes in a remote location?
It is extremely important to keep in mind that communications between the nodes in a MySQL Cluster are not secure; they are neither encrypted nor safeguarded by any other protective mechanism. The most secure configuration for a cluster is in a private network behind a firewall, with no direct access to any Cluster data or management nodes from outside. (For SQL nodes, you should take the same precautions as you would with any other instance of the MySQL server.)
It is very doubtful in any case that a cluster would perform reliably under such conditions, as MySQL Cluster was designed and implemented with the assumption that it would be run under conditions guaranteeing dedicated high-speed connectivity such as that found in a LAN setting using 100 Mbps or gigabit Ethernet (preferably the latter). We neither test nor warrant its performance using anything slower than this.
Do I have to learn a new programming or query language to use Cluster?
No. While some specialized commands are used to manage and configure the cluster itself, only standard (My)SQL queries and commands are required for:
Creating, altering, and dropping tables
Inserting, updating, and deleting table data
Creating, changing, and dropping primary and unique indexes
Configuring and managing SQL nodes (MySQL servers)
How do I find out what an error or warning message means when using Cluster?
There are two ways in which this can be done:
From within the MySQL Monitor, use SHOW ERRORS or SHOW WARNINGS immediately upon being notified of the error or warning condition. These can also be displayed in MySQL Query Browser.
From a system shell prompt, use perror --ndb
error_code
.
Is MySQL Cluster transaction-safe? What isolation levels are supported?
Yes: For tables created with the
NDB
storage engine, transactions are
supported. In MySQL 5.0, Cluster supports only
the READ_COMMITTED
transaction isolation
level.
What table types does Cluster support?
NDB
is the only MySQL storage engine which
supports clustering.
(It is possible to create tables using other storage engines
such as MyISAM
or InnoDB
on a MySQL server being used for clustering, but these
non-NDB
tables will
not participate in the
cluster.)
What does “NDB” mean?
This stands for “Network Database”.
Which version(s) of the MySQL software support Cluster? Do I have to compile from source?
Cluster is supported in all MySQL-max binaries in the
5.0 release series, except as noted in the
following paragraph. You can determine whether or not your
server has NDB support using either of the commands
SHOW VARIABLES LIKE 'have_%';
or
SHOW ENGINES;
. (See
Section 5.1.2, “The mysqld-max Extended MySQL Server” for more information.)
Linux users, please note that NDB
is
not included in the standard MySQL server
RPMs. Beginning with MySQL 5.0.4, there are separate RPM
packages for the NDB storage engine and accompanying
management and other tools; see the NDB RPM Downloads section
of the MySQL 5.0 Downloads page for these. (Prior
to 5.0.4, you had to use the -max
binaries
supplied as .tar.gz
archives. This is
still possible, but is not required, so you can use your Linux
distribution's RPM manager if you prefer.) You can also obtain
NDB support by compiling the -max
binaries
from source, but it is not necessary to do so simply to use
MySQL Cluster. To download the latest binary, RPM, or source
distibution in the MySQL 5.0 series, visit
http://dev.mysql.com/downloads/mysql/5.0.html.
How much RAM do I need? Is it possible to use disk memory at all?
Currently, Cluster is in-memory only. This means that all table data (including indexes) is stored in RAM. Therefore, if your data takes up 1 gigabyte of space and you wish to replicate it once in the cluster, you need 2 gigabytes of memory to do so. This in addition to the memory required by the operating system and any applications running on the cluster computers.
You can use the following formula for obtaining a rough estimate of how much RAM is needed for each data node in the cluster:
(SizeofDatabase * NumberOfReplicas * 1.1 ) / NumberOfDataNodes
To calculate the memory requirements more exactly requires determining, for each table in the cluster database, the storage space required per row (see Section 11.5, “Column Type Storage Requirements” for details), and multiplying this by the number of rows. You must also remember to account for any column indexes as follows:
Each primary key or hash index created for an
NDBCluster
table requires 21-25 bytes
per record. These indexes use
IndexMemory
.
Each ordered index requires 10 bytes storage per record,
using DataMemory
.
Creating a primary key or unique index also creates an
ordered index, unless this index is created with
USING HASH
. In other words, if created
without USING HASH
, a primary key or
unique index on a Cluster table takes up 31-35 bytes per
record in MySQL 5.0.
Note that creating MySQL Cluster tables with
USING HASH
for all primary keys and
unique indexes will generally cause table updates to run
more quickly. This is due to the fact that less memory is
required (since no ordered indexes are created), and that
less CPU must be utilised (since fewer indexes must be
read and possibly updated).
It is especially important to keep in mind that
every MySQL Cluster table must have a primary
key. The NDB
storage engine
creates a primary key automatically if none is defined, and
this primary key is created without USING
HASH
.
Currently there is no easy way in MySQL 5.0 to
determine exactly how much memory is being used for storage of
Cluster indexes at any given time; however, warnings are
written to the Cluster log when 80% of available
DataMemory
and/or
IndexMemory
is in use, and again when 85%,
90%, and so on is in use.
We often see questions from users who report that, when they are trying to populate a Cluster database, the loading process terminates prematurely and an error message like this one is observed:
ERROR 1114: The table 'my_cluster_table' is full
When this occurs, the cause is very likely to be that your
setup does not provide sufficient RAM for all table data and
all indexes, including the primary key required by
the NDB
storage engine and automatically
created in the event that the table definition does not
include the definition of a primary key.
It is also worth noting that all data nodes should have the same amount of RAM, as no data node in a cluster can use more memory than the least amount available to any individual data node. In other words, if there are three computers hosting Cluster data nodes, with two of these having three gigabytes of RAM available to store Cluster data, and one having only one GB RAM, then each data node can devote only one GB to clustering.
In the event of a catastrophic failure — say, for instance, the whole city loses power and my UPS fails — would I lose all my data?
All committed transactions are logged. Therefore, while it is possible that some data could be lost in the event of a catastrophe, this should be quite limited. Data loss can be further reduced by minimising the number of operations per transaction. (It is not a good idea to perform large numbers of operations per transaction in any case.)
Is it possible to use FULLTEXT
indexes with Cluster?
FULLTEXT
indexing is not currently
supported by the NDB
storage engine, or by
any storage engine other than MyISAM
. We
are working to add this capability in a future release.
Can I run multiple nodes on a single computer?
It is possible but not advisable. One of the chief reasons to run a cluster is to provide redundancy; in order to enjoy the full benefits of this redundancy, each node should reside on a separate machine. If you place multiple nodes on a single machine and that machine fails, you lose all of those nodes. Given that MySQL Cluster can be run on commodity hardware loaded with a low-cost (or even no-cost) operating system, it is well worth the expense of an extra machine or two in order to safeguard mission-critical data. It also worth noting that the requirements for a cluster host running a management node are minimal; this task can be accomplished with a 200 MHz Pentium CPU and sufficient RAM for the operating system plus a small amount of overhead for the ndb_mgmd and ndb_mgm processes.
Can I add nodes to a cluster without restarting it?
Not at present. A simple restart is all that is required for adding new MGM or SQL nodes to a Cluster. When adding data nodes the process is more complex, and requires the following steps:
Make a complete backup of all Cluster data.
Completely shut down the cluster and all cluster node processes.
Restart the cluster, using the --initial
startup option.
Restore all cluster data from the backup.
In a future MySQL Cluster release series, we hope to implement a “hot” reconfiguration capability for MySQL Cluster in order to minimize (if not eliminate) the requirement for restarting the cluster when adding new nodes.
Are there any limitations that I should be aware of when using Cluster?
NDB
tables in MySQL are subject to the
following limitations:
Not all character sets and collations are supported.
FULLTEXT
indexes and prefix indexes are
not supported. Only complete columns may be indexed.
Chapter 17, Spatial Extensions in MySQL are not supported.
Only complete rollbacks for transactions are supported. Partial rollbacks and rollbacks to save points are not supported.
The maximum number of attributes allowed per table is 128, and attribute names cannot be any longer than 31 characters. For each table, the maximum combined length of the table and database names is 122 characters.
The maximum size for a table row is 8 kilobytes, not
counting BLOB
s. There is no set limit
for the number of rows per table; table size limits depend
on a number of factors, in particular on the amount of RAM
available to each data node.
The NDB
engine does not support foreign
key constraints. As with MyISAM
tables,
these are ignored.
Query caching is not supported.
For additional information on Cluster limitations, see Section 16.8, “Known Limitations of MySQL Cluster”.
How do I import an existing MySQL database into a cluster?
You can import databases into MySQL Cluster much as you would
with any other version of MySQL. Other than the limitation
mentioned in the previous question, the only other special
requirement is that any tables to be included in the cluster
must use the NDB
storage engine. This means
that the tables must be created with
ENGINE=NDB
or
ENGINE=NDBCLUSTER
. It is also possible to
convert existing tables using other storage engines to
NDB Cluster
using ALTER
TABLE
, but requires an additional workaround; see
Section 16.8, “Known Limitations of MySQL Cluster” for details.
How do cluster nodes communicate with one another?
Cluster nodes can communicate via any of three different protocols: TCP/IP, SHM (shared memory), and SCI (Scalable Coherent Interface). Where available, SHM is used by default between nodes residing on the same cluster host. SCI is a high-speed (1 gigabit per second and higher), high-availability protocol used in building scalable multi-processor systems; it requires special hardware and drivers. See Section 16.7, “Using High-Speed Interconnects with MySQL Cluster” for more about using SCI as a transport mechanism in MySQL Cluster.
What is an “arbitrator”?
If one or more nodes in a cluster fail, it is possible that not all cluster nodes will not be able to “see” one another. In fact, it is possible that two sets of nodes might become isolated from one another in a network partitioning, also known as a “split brain” scenario. This type of situation is undesirable because each set of nodes tries to behave as though it is the entire cluster.
When cluster nodes go down, there are two possibilities. If more than 50% of the remaining nodes can communicate with each other, then we have what is sometimes called a “majority rules” situation, and this set of nodes is considered to be the cluster. The arbitrator comes into play when there is an even number of nodes: in such cases, the set of nodes to which the arbitrator belongs is considered to be the cluster, and nodes not belonging to this set are shut down.
The above information is somewhat simplified; a more complete explanation taking into account node groups follows below:
When all nodes in at least one node group are alive, network
partitioning is not an issue, because no one portion of the
cluster can form a functional cluster. The real problem arises
when no single node group has all its nodes alive, in which
case network partitioning (the “split-brain”
scenario) becomes possible. Then an arbitrator is required.
All cluster nodes recognise the same node as the arbitrator,
which is normally the management server; however, it is
possible to configure any of the MySQL Servers in the cluster
to act as the arbirtrator instead. The arbitrator accepts the
first set of cluster nodes to contact it, and tells the
remaining set to shut down. Arbitrator selection is controlled
by the ArbitrationRank
configuration
parameter for MySQL Server and management server nodes. (See
Section 16.4.4.4, “Defining the MySQL Cluster Management Server” for details.)
It should also be noted that the role of arbitrator does not
in and of itself impose any heavy demands upon the host so
designated, and thus the artitrator host does not need to be
particularly fast or to have extra memory especially for this
purpose.
What column types are supported by MySQL Cluster?
MySQL Cluster supports all of the usual MySQL column types,
with the exception of those associated with MySQL's spatial
extensions. (See
Chapter 17, Spatial Extensions in MySQL.) In addition,
there are some differences with regard to indexes when used
with NDB
tables.
Note: In MySQL
5.0, Cluster tables (that is, tables created with
ENGINE=NDBCLUSTER
) have only fixed-width
rows. This means that (for example) each record containing a
VARCHAR(255)
column will will require 256
bytes of storage for that column, regardless of the size of
the data stored therein. This issue is expected to be fixed in
a future MySQL release series.
See Section 16.8, “Known Limitations of MySQL Cluster” for more information about these issues.
How do I start and stop MySQL Cluster?
It is necessary to start each node in the cluster separately, in the following order:
Start the management node with the ndb_mgmd command.
Start each data node with the ndbd command.
Start each MySQL server (SQL node) using mysqld_safe --user=mysql &.
Each of these commands must be run from a system shell on the machine housing the affected node. You can verify the the cluster is running by starting the MGM management client ndb_mgm on the machine housing the MGM node.
What happens to cluster data when the cluster is shut down?
The data held in memory by the cluster's data nodes is written to disk, and is reloaded in memory the next time that the cluster is started.
To shut down the cluster, enter the following in a shell on the machine hosting the MGM node:
shell> ndb_mgm -e shutdown
This will cause the ndb_mgm, ndb_mgm, and any ndbd processes to terminate gracefully. MySQL servers running as Cluster SQL nodes can be stopped using mysqladmin shutdown.
For more information, see Section 16.6.2, “Commands in the Management Client” and Section 16.3.6, “Safe Shutdown and Restart”.
Is it helpful to have more than one management node for a cluster?
It can be helpful as a fail-safe. Only one MGM node controls the cluster at any given time, but it is possible to configure one MGM as primary, and one or more additional management nodes to take over in the evnt that the primary MGM node fails.
Can I mix different kinds of hardware and operating systems in a Cluster?
Yes, so long as all machines and operating systems are the same endian. It is also possible to use different MySQL Cluster releases on different nodes; however, we recommend this be done only as part of a rolling upgrade procedure.
Can I run two data nodes on a single host? Two SQL nodes?
Yes, it is possible to do this. In the case of multiple data nodes, each node must use a different data directory. If you want to run multiple SQL nodes on one machine, then each instance of mysqld must use a different TCP/IP port.
Can I use hostnames with MySQL Cluster?
Yes, it is possible to use DNS and DHCP for cluster hosts. However, if your application requires “five nines” availability, we recommend using fixed IP addresses. This is because making communication between Cluster hosts dependent on such services introduces additional points of failure, and the fewer of these, the better.
The following terms are useful to an understanding of MySQL Cluster or have specialized meanings when used in relation to it.
Cluster:
In its generic sense, a cluster is a set of computers functioning as a unit and working together to accomplish a single task.
NDB
Cluster
:
This is the storage engine used in MySQL to implement data storage, retrieval, and management distributed amongst several computers.
MySQL Cluster:
This refers to a group of computers working together using the
NDB
storage engine to support a distributed
MySQL database in a shared-nothing
architecture using in-memory
storage.
Configuration files:
Text files containing directives and information regarding the cluster, its hosts, and its nodes. These are read by the cluster's management nodes when the cluster is started. See Section 16.4.4, “Configuration File” for details.
Backup:
A complete copy of all cluster data, transactions and logs, saved to disk or other long-term storage.
Restore:
Returning the cluster to a previous state, as stored in a backup.
Checkpoint:
Generally speaking, when data is saved to disk, it is said
that a checkpoint has been reached. More specific to Cluster,
it is a point in time where all committed transactions are
stored on disk. With regard to the NDB
storage engine, there are two sorts of checkpoints which work
together to ensure that a consistent view of the cluster's
data is maintained:
Local Checkpoint (LCP):
This is a checkpoint that is specific to a single node; however, LCP's take place for all nodes in the cluster more or less concurrently. An LCP involves saving all of a node's data to disk, and so usually occurs every few minutes. The precise interval varies, and depends upon the amount of data stored by the node, the level of cluster activity, and other factors.
Global Checkpoint (GCP):
A GCP occurs every few seconds, when transactions for all nodes are synchronised and the redo-log is flushed to disk.
Cluster host:
A computer making up part of a MySQL Cluster. A cluster has both a physical structure and a logical structure. Physically, the cluster consists of a number of computers, known as cluster hosts (or more simply as hosts. See also Node and Node group below.
Node:
This refers to a logical or functional unit of MySQL Cluster, and is sometimes also referred to as a cluster node . In the context of MySQl Cluster, we use the term “node” to indicate a process rather than a physical component of the cluster. There are three node types required to implement a working MySQL Cluster. These are:
Management (MGM) nodes:
Manages the other nodes within the MySQL Cluster. It provides configuration data to the other nodes; starts and stops nodes; handles network partitioning; creates backups and restores from them, and so forth.
SQL (MySQL server) nodes:
Instances of MySQL Server which serve as front ends to data kept in the cluster's data nodes. Clients desiring to store, retrieve, or update data can access an SQL node just as they would any other MySQL Server, employing the usual authentication methods and API's; the underlying distribution of data between node groups is transparent to users and applications. SQL nodes access the cluster's databases as a whole without regard to the data's distribution across different data nodes or cluster hosts.
Data nodes:
These nodes store the actual data. Table data fragments are stored in a set of node groups; each node group stores a different subset of the table data. Each of the nodes making up a node group stores a replica of the fragment for which that node group is responsible. Currently a single cluster can support up to 48 data nodes total.
It is possible for more than one node to co-exist on a single machine. (In fact, it is even possible to set up a complete cluster on one machine, although one would almost certainly not want to do this in a production environment.) It may be helpful to remember that, when working with MySQL Cluster, the term host refers to a physical component of the cluster whereas a node is a logical or functional component (that is, a process).
Note Regarding Obsolete Terms: In older versions of the MySQL Cluster documentation, data nodes were sometimes referred to as “database nodes”, “DB nodes”, or occasionally “storage nodes”. In addition, SQL nodes were sometimes known as “client nodes” or “API nodes”. This older terminology has been deprecated in order to minimize confusion, and for these reasons should be avoided.
Node group:
A set of data nodes. All data nodes in a node group contain the same data (fragments), and all nodes in a single group should reside on different hosts. It is possible to control which nodes belong to which node groups.
Node failure:
MySQL Cluster is not solely dependent upon the functioning of any single node making up the cluster; the cluster can continue to run if one or more nodes fail. The precise number of node failures that a given cluster can tolerate depends upon the number of nodes and the cluster's configuration.
Node restart:
The process of restarting a failed cluster node.
Initial node restart:
The process of starting a cluster node with its filesystem removed. This is sometimes used in the course of software upgrades and in other special circumstances.
System crash (or system failure):
This can occur when so many cluster nodes have failed that the cluster's state can no longer be guaranteed.
System restart:
The process of restarting the cluster and reinitialising its state from disk logs and checkpoints. This is required after either a planned or an unplanned shutdown of the cluster.
Fragment:
A portion of a database table; in the NDB
storage engine, a table is broken up into and stored as a
number of fragments. A fragment is sometimes also called a
“partition”; however, “fragment” is
the preferred term. Tables are fragmented in MySQL Cluster in
order to facilitate load balancing between machines and nodes.
Replica:
Under the NDB
storage engine, each table
fragment has number of replicas stored on other data nodes in
order to provide redundancy. Currently there may be up 4
replicas per fragment.
Transporter:
A protocol providing data transfer between nodes. MySQL Cluster currently supports 4 different types of transporter connections:
TCP/IP (local)
This is, of course, the familiar network protocol that underlies HTTP, FTP (and so on) on the Internet.
TCP/IP (remote)
Same as above, except as used for communicating remotely.
SCI
Scalable Coherent Interface is a high-speed protocol used in building multiprocessor systems and parallel-processing applications. Use of SCI with MySQL Cluster requires specialized hardware and is discussed in Section 16.7.1, “Configuring MySQL Cluster to use SCI Sockets”. For a basic introduction to SCI, see this essay at dolphinics.com.
SHM
Unix-style shared
memory segments. Where
supported, SHM is used automatically to connect nodes
running on the same host. The
Unix
man page for shmop(2)
is a good
place to begin obtaining additional information about this
topic.
Note: The cluster transporter is internal to the cluster. Applications using MySQL Cluster communicate with SQL nodes just as they do with any other version of MySQL Server (via TCP/IP, or through the use of Unix sockets or Windows named pipes). Queries can be sent and results retrieved using the standard MySQL APIs.
NDB
:
This stands for Network
Database,
and refers to the storage engine used to enable MySQL Cluster.
The NDB
storage engine supports all the
usual MySQL column types and SQL statements, and is
ACID-compliant. This engine also provides full support for
transactions (commits and rollbacks).
Share-nothing architecture:
The ideal architecture for a MySQL Cluster. In a true share-nothing setup, each node runs on a separate host. The advantage such an arrangement is that there no single host or node can act as single point of failure or as a performance bottle neck for the system as a whole.
In-memory storage:
All data stored in each data node is kept in memory on the node's host computer. For each data node in the cluster, you must have available an amount of RAM equal to the size of the database times the number of replicas, divided by the number of data nodes. Thus, if the database takes up 1 gigabyte of memory, and you wish to set up the cluster with 4 replicas and 8 data nodes, a minimum of 500 MB memory will be required per node. Note that this is in addition to any requirements for the operating system and any other applications that might be running on the host.
Table:
As is usual in the context of a relational database, the term “table” denotes an ordered set of identically structured records. In MySQL Cluster, a database table is stored in a data node as a set of fragments, each of which is replicated on additional data nodes. The set of data nodes replicating the same fragment or set of fragments is referred to as a node group.
Cluster programs:
These are command-line programs used in running, configuring, and administering MySQL Cluster. They include both server daemons:
ndbd:
The data node daemon (runs a data node process)
ndb_mgmd:
The management server daemon (runs a management server process)
and client programs:
ndb_mgm:
The management client (provides an interface for executing management commands)
ndb_waiter:
Used to verify status of all nodes in a cluster
ndb_restore:
Restores cluster data from backup
For more about these programs and their uses, see Section 16.5, “Process Management in MySQL Cluster”.
Event log:
MySQL Cluster logs events by category (startup, shutdown, errors, checkpoints, and so on), priority, and severity. A complete listing of all reportable events may be found in Section 16.6.3, “Event Reports Generated in MySQL Cluster”. Event logs are of two types:
Cluster log:
Keeps a record of all desired reportable events for the cluster as a whole.
Node log:
A separate log which is also kept for each individual node.
Under normal circumstances, it is necessary and sufficient to keep and examine only the cluster log. The node logs need be comsulted only for application development and debugging purposes.