- Solid Information Technology, Ltd -

solidDB for MySQL 5.1 User Guide

Version: solidDB-0080

Date: 15.11.2007

This product is distributed under the GPL License V.2.

All rights reserved. This documentation is not distributed under a GPL license.


Table of Contents

1 solidDB for MySQL Overview
2 Solid Contact Information
3 Installing solidDB for MySQL
3.1 Installing solidDB for MySQL on a Linux Platform
4 Compiling from Source Distribution
4.1 Building MySQL Server 5.1 and solidDB Storage Engine
5 Upgrading MySQL from 5.0 to 5.1
6 Upgrading MySQL from 5.1 without solidDB to 5.1 with solidDB
7 solidDB for MySQL Configuration
8 Starting the Server and Activating solidDB for MySQL
8.1 Starting the Server
8.2 Opening the MySQL Query Tool
8.3 Creating a Database
8.4 Shutting Down the Database
9 solidDB for MySQL Startup Options and System Variables
9.1 solidDB for MySQL Command Options
9.2 solidDB for MySQL System Variables
10 solidDB Data Dictionary
10.1 solidDB Data Dictionary Installation
10.2 Using solidDB Data Dictionary
10.3 Removing solidDB Data Dictionary
10.4 Accessing solidDB Data Dictionary
10.5 solidDB Data Dictionary Contents
10.5.1 SOLIDDB_ADMIN_COMMANDS
10.5.2 SOLIDDB_SYS_TABLES
10.5.3 SOLIDDB_SYS_COLUMNS
10.5.4 SOLIDDB_SYS_COLUMNS_AUX
10.5.5 SOLIDDB_SYS_KEYS
10.5.6 SOLIDDB_SYS_KEYPARTS
10.5.7 SOLIDDB_SYS_KEYPARTS_AUX
10.5.8 SOLIDDB_SYS_FORKEYS
10.5.9 SOLIDDB_SYS_FORKEYPARTS
10.5.10 SOLIDDB_SYS_SCHEMAS
10.5.11 SOLIDDB_SYS_SEQUENCES
10.5.12 SOLIDDB_SYS_BLOBS
10.5.13 SOLIDDB_SYS_CARDINAL
10.5.14 SOLIDDB_SYS_INFO
10.5.15 SOLIDDB_SYS_TABLEMODES
10.5.16 SOLIDDB_SYS_COLLATIONS
11 Creating and Using solidDB Tables
12 Character Sets and Collations
13 Limitations on solidDB Tables in This Release
14 Dynamic Configuration Settings
14.1 soliddb_admin_command
14.2 soliddb_backupdir
14.3 soliddb_filespec
14.4 soliddb_durability_level
14.5 soliddb_checkpoint_time
14.6 soliddb_lock_wait_timeout
14.7 soliddb_checkpoint_interval
15 Foreign Key Constraints
15.1 Referential Actions
16 Transaction Durability
17 How AUTO_INCREMENT Columns Work in solidDB
18 solidDB and TRANSACTION ISOLATION LEVEL
19 solidDB Performance Tuning Tips
20 solidDB Performance Monitoring
21 Concurrency Control
21.1 Pessimistic Concurrency Control
21.2 Optimistic Concurrency Control
21.3 Differences Between Optimistic and Pessimistic Concurrency Control
22 Implementation of Multiversioning
23 solidDB Table and Index Structures
23.1 Main Storage Tree
23.2 Bonsai Tree
24 solidDB Status
25 Show Status
26 Obtaining solidDB for MySQL Version
27 Troubleshooting solidDB
27.1 Cachesize Too Large
27.2 Cachesize Too Small
28 solidDB File Space Management and Disk I/O
29 solidDB Error Handling
30 MySQL Drivers
Index

Chapter 1. solidDB for MySQL Overview

solidDB for MySQL is a turbo-charged version of MySQL database that includes MySQL Server, solidDB Storage Engine and MyISAM storage engine. It also comes with an online backup capability that is included at no additional cost. It behaves like MySQL Server since it includes the same code and uses the same interface and drivers. It is fully transactional and scales well in multi-CPU environments so it is well suited to support large numbers of concurrent users and heavy transaction volumes. It is meant for OLTP workloads as opposed to data warehousing ones such as OLAP.

solidDB for MySQL is based on Solid's proven transactional product solidDB 6, which is a fully-featured relational database that is being used in products from companies including HP, Siemens, Nortel and NEC. solidDB for MySQL supports mission critical applications that require a high level of reliability and large transaction volumes. solidDB for MySQL is licensed under GNU GPL.

solidDB Storage Engine is a multi-threaded, transactional storage engine for MySQL Server. It is designed for mission-critical implementations that require a robust, transactional database able to fully leverage multi-processor environments to support heavy transaction volumes and a large number of concurrent users. solidDB Storage Engine supports full ACID compliance with configurable transaction isolation levels, both optimistic and pessimistic concurrency control, Multi-Version Concurrency Control (MVCC) with non-blocking reads and writes, row-level locking, and support for foreign keys and referential integrity.

In Release 5.0, solidDB Storage Engine is statically linked with MySQL Server 5.0.

In Release 5.1, which is currently available as Beta, solidDB Storage Engine supports dynamic linking with MySQL Server 5.1, in accordance with MySQL Server 5.1's Pluggable Storage Engine Architecture.

Chapter 2. Solid Contact Information

Contact information for Solid:

Web site: http://www.soliddb.com

Sales inquiries:

Technical support:

Marketing:

Offices

  • Americas

  • Asia Pacific

  • EMEA

Americas

Solid World Headquarters

    20400 Stevens Creek Blvd, Suite 200

    Cupertino

    CA

    95014

    USA

    +1 408 4544700

    +1 408 4544900

    

Asia Pacific

Solid APAC Headquarters

    Solid K.K.

    43rd Floor

    The Landmark Tower Yokohama

    2-2-1 Minatomirai, Nishi-ku

    Yokohama

    220-8143

    Japan

    +81 45 2242525

    +81 45 2242535

    

EMEA

 Solid EMEA Headquarters

    Italahdenkatu 22 B

    FIN-00210

    Helsinki

    Finland

    +358 42488881

    +358 9 2782877

    

Chapter 3. Installing solidDB for MySQL

solidDB for MySQL 5.1 is currently available as a Beta release on Linux only. solidDB Storage Engine supports dynamic linking with MySQL Server 5.1, in accordance with MySQL Server 5.1's Pluggable Storage Engine Architecture. In this release, solidDB Storage Engine and MySQL Server 5.1 Release Candidate (5.1.22) must be downloaded separately.

3.1 Installing solidDB for MySQL on a Linux Platform

solidDB for MySQL is delivered as a tar.gz package. Extract the package under a non-root user's home directory or to a directory of your choice. The commands are:

shell> tar zxvf solidmysql-<sw_version>-linux-i686-VERSION.tar.gz

shell> cd solidmysql-<sw_version>-linux-i686-VERSION

Copy libsoliddb.so to MySQL library directory

Comment all solidDB configuration parameters from the defaults file in use(.my.cnf).

mysqld --skip-innodb

mysql -u root mysql

Next, give the following SQL commands:

SQL> INSERT INTO plugin VALUES ('soliddb', 'libsoliddb.so');

SQL> commit;

SQL>exit;

Next, give the following command:

killall mysqld

Edit the ~/.my.cnf file to contain soliddb (uncomment options)

When you run mysqld_safe, you must define a configuration file for it by using the --defaults-file command line option. Define, for example, the support-files/my-soliddb.cnf as the configuration file.

shell> bin/mysqld_safe --default-storage-engine=solidDB --defaults-file=support-files/my-soliddb.cnf &

You can create a solidDB database (solid.db) in the data/ directory as shown here:

shell> cd bin

shell> mysql -u root

shell> create database solid;

shell> use solid;

[Note]Note

If you want to run mysqld as root, you must supply --user=<username> to mysql_install_db and mysqld_safe. In this case, the server is started as that user's process. If you are root and try to do this without the --user option, the server will fail to start.

Chapter 4. Compiling from Source Distribution

This chapter explains how to compile solidDB for MySQL from source for the Linux platform.

4.1 Building MySQL Server 5.1 and solidDB Storage Engine

This chapter describes how to build the solidDB pluggable storage engine for MySQL 5.1 on Linux.

  1. Download the source distribution of MySQL 5.1.22-rc from:

    http://dev.mysql.com/get/Downloads/MySQL-5.1/mysql-5.1.22-rc.tar.gz/from/pick

  2. Download the Beta source distribution of solidDB from:

    ftp://ftp.solidtech.com/pub/incoming/soliddbse/solidmysql-5.1.22-0080.tar.gz

  3. Extract the .tar.gz packages in your development directory. In this document, we assume that the development directory is /home/mysql51.

    tar xvfz mysql-5.1.22-rc.tar.gz

    tar xvfz solidmysql-5.1.22-0080.tar.gz

  4. Go to the source directory:

    cd mysql-5.1.22-rc

  5. Build, but do NOT make install:

    ./BUILD/compile-pentium-max

  6. Create directories:

    cd ..

    mkdir ~/lib

    mkdir ~/lib/mysql

    mkdir ~/sqldata

  7. Go to the solidDB source directory:

    cd solidmysql-5.1.22-0080

  8. Configure and build solidDB

    ./configure --with-mysql=${HOME}/mysql-5.1.22-rc --libdir=${HOME}/lib/mysql

    where:

    --with-mysql indicates the path to the MySQL source tree.

    --libdir indicates the plug-in installation directory.

    After configuration, make and install MySQL:

    $ make
    $ make install
              

    These commands copy the plug-in shared library to the directory where the MySQL server can find it.

  9. Enter the following commands to test run and finalise the installation:

    cd ../mysql-5.1.22-rc/mysql-test

    ./mysql-test-run.pl innodb

    cp -r var/master-data/mysql ~/sqldata/.

    cd ../sql

    mysqld --skip-innodb

    mysql -u root mysql

  10. Next, give the following SQL commands:

    SQL> INSERT INTO plugin VALUES ('soliddb', 'libsoliddb.so');

    SQL> commit;

    SQL>exit;

  11. Next, give the following command:

    killall mysqld

  12. Edit the ~/.my.cnf file to contain soliddb (uncomment options)

  13. Finally, give the following command:

    /home/mysql51/mysql-5.1.22-rc/sql/mysqld

  14. The installation process is complete.

Chapter 5. Upgrading MySQL from 5.0 to 5.1

[Important]Important

Before upgrading to MySQL 5.1, backup your database by using MySQL 5.0.

You can upgrade the MySQL database by using mysql_upgrade and it should be executed each time you upgrade MySQL. It checks all tables in all databases for incompatibilities with the current version of MySQL Server see (http://dev.mysql.com/doc/refman/5.1/en/mysql-upgrade.html). solidDB for MySQL files do not need any additional upgrade procedure.

[Note]Note

You must use the same configuration of database files and block sizes in MySQL 5.1 as you used in MySQL 5.0.

To upgrade the MySQL database, proceed as follows:

  1. Backup your database by using MySQL 5.0.

  2. Comment all solidDB configuration parameters from the defaults file in use(.my.cnf).

  3. Upgrade the server binary from 5.0 to 5.1.

  4. Execute mysql_upgrade.

  5. Download and install solidDB Storage Engine for MySQL 5.1

  6. Start the server.

  7. Start MySQL command client and give the following SQL commands.

    SQL> INSERT INTO plugin VALUES ('soliddb', 'libsoliddb.so');

    SQL> commit;

    SQL> EXIT

  8. Shutdown the server.

  9. Uncomment all solidDB configuration parameters from. the defaults file in use(.my.cnf).

  10. You can now start the server with solidDB support.

Chapter 6. Upgrading MySQL from 5.1 without solidDB to 5.1 with solidDB

[Important]Important

Backup your database before upgrading.

You can upgrade the MySQL database by using mysql_upgrade and it should be executed each time you upgrade MySQL. It checks all tables in all databases for incompatibilities with the current version of MySQL Server see (http://dev.mysql.com/doc/refman/5.1/en/mysql-upgrade.html). solidDB for MySQL files do not need any additional upgrade procedure.

[Note]Note

You must use the same configuration of database files and block sizes in MySQL 5.1 as you used in MySQL 5.0.

To upgrade the MySQL database, proceed as follows:

  1. Backup your database.

  2. Download and install solidDB Storage Engine for MySQL 5.1

  3. Comment all solidDB configuration parameters from the defaults file in use (.my.cnf).

  4. Execute mysql_upgrade.

  5. Start the server.

  6. Start MySQL command client and give the following SQL commands.

    SQL> INSERT INTO plugin VALUES ('soliddb', 'libsoliddb.so');

    SQL> commit;

    SQL> EXIT

  7. Shutdown the server.

  8. Uncomment all solidDB configuration parameters from. the defaults file in use(.my.cnf).

  9. You can now start the server with solidDB support.

Chapter 7. solidDB for MySQL Configuration

The solidDB Storage Engine is enabled by default. If you do not want to use solidDB tables, you can add the skip-soliddb option to your MySQL option file.

This section contains representative examples of solidDB configuration parameters. Refer to Chapter 9, solidDB for MySQL Startup Options and System Variables for additional information about solidDB-related configuration parameters.

To set up the solidDB database files, use the soliddb_filespec option in the [mysqld] section of the .my.cnf option file. The value of soliddb_filespec should be a list of one or more database file specifications. If you name more than one data file, separate them by comma (“,”) characters:

soliddb_filespec=database_file[,database_file2]...

For example,

[mysqld]
soliddb_filespec=soliddb1 10M
    

This setting configures a single 10MB database file named soliddb1. No location for the database file is given. By default, solidDB creates it in the MySQL data directory. The full syntax for a database file specification includes the filename and the file-size:

file_name file_size

solidDB creates tablespace files in the MySQL data directory by default. To specify a location explicitly, use the soliddb_filespec option with a path. For example, to use two files named soliddb1 and soliddb2 but create them in the /soliddb directory, configure solidDB like this:

[mysqld]
soliddb_filespec=/soliddb/soliddb1 10M,/soliddb/soliddb2 20M
  

For more information on file management, see Chapter 28, solidDB File Space Management and Disk I/O.

If you want to tune other mysqld and solidDB parameters, the following values are typical and would suit most users:

[mysqld]
skip-external-locking
max_connections=1024
read_buffer_size=1M
sort_buffer_size=1M
#
# If you are using solidDB tables only, set key_buffer_size to 5%
# of main memory. If you have large MyISAM tables, divide the main
# memory between solidDB and MyISAM. You can do this by estimating
# the number of rows on MyISAM tables and solidDB tables and calculating
# rows_in_myisam / (rows_in_myisam + rows_in_soliddb) and then using
# this information to set your key_buffer_size and soliddb_cache_size.
# Remember that the total size should be < 80% of system main memory.
key_buffer_size=value
#
# Set the cache size to 70-80% of your ram
#
#
soliddb_cache_size=value
#
# Set durability to strict
#
set-variable = soliddb_durability_level=3

Chapter 8. Starting the Server and Activating solidDB for MySQL

This chapter explains basic tasks needed to start solidDB for MySQL.

8.1 Starting the Server

If you use Linux, start the solidDB for MySQL server by using mysqld_safe. mysqld_safe is a utility that starts solidDB for MySQL after scanning for the needed files and directories (such as the data directory) below the current working directory. In other words, if you have installed solidDB for MySQL under your home directory, mysqld_safe will find it when your current working directory is your home directory. The command syntax is as follows:

mysqld_safe --mysqld=<mysql-server-name> --default-storage-engine=solidDB

Go to your solidDB for MySQL installation data directory and issue, for example, the following command:

mysqld_safe --mysqld=mysqld --default-storage-engine=solidDB

That command starts the solidDB for MySQL server containing solidDB Storage Engine.

When started, solidDB for MySQL creates, if necessary, the solidDB database file, transaction log files, and the solidDB message output file to the solidDB for MySQL data directory.

The default solidDB filenames are:

  • solid.db for the database file.

  • sol#####.log for transaction logs. Files start from sol00001.log.

  • solmsg.out for message output.

  • solerror.out for errors occurring during the startup of solidDB Storage Engine.

The names and locations of these files are defined in the solidDB for MySQL configuration file, and can be changed according to your specific requirements.

8.2 Opening the MySQL Query Tool

[Note]Note

These instructions are for the command-line query tool, not for MySQL Query Browser.

You can start the query tool from the Linux prompt as follows:

shell> mysql -u root

8.3 Creating a Database

You can create a new database by entering commands as follows:

mysql> create database dba;

Query OK, 1 row affected (0.14 sec)

mysql> use dba;

Database changed

You are now ready to use the database.

8.4 Shutting Down the Database

You can shut down the database with the MySQL mysqladmin utility by entering a command as follows:

shell> mysqladmin -u root shutdown

This command will shut down solidDB for MySQL. solidDB for MySQL will first perform a checkpoint, close the files it is using, and then stop running.

Chapter 9. solidDB for MySQL Startup Options and System Variables

This section describes the command-line options and system variables for solidDB for MySQL. System variables have two possible states: they are either true or false. System variables can be enabled at server startup by naming them, or disabled by using a skip- prefix. For example, to enable or disable deleting solidDB transaction log files after each successful checkpoint, you can use --soliddb_checkpoint_deletelog or --skip-soliddb_checkpoint_deletelog on the command line, or soliddb_checkpoint_deletelog or skip-soliddb_checkpoint_deleletelog in an option file.

System variables that take a numeric value can be specified as --var_name=value on the command line or as var_name=value in option files.

9.1 solidDB for MySQL Command Options

  • soliddb

    This command option enables solidDB Storage Engine, if the server was compiled with solidDB support. Use skip-soliddb to disable solidDB.

  • soliddb_checkpoint_deletelog

    If this command option is set, the server deletes the transaction log file(s) after each successful checkpoint. This saves disk space, but makes it impossible to recover data by rolling forward the logs. The transaction logs contain a copy of the transactions executed by the server. If the database file is erased or corrupted, and if you have kept the transaction log files, you can restore the data by restoring the backup database file and then rolling forward all the transaction logs that accumulated since the last backup. If you have deleted those transaction logs, you will lose all transactions since the last successful backup.

9.2 solidDB for MySQL System Variables

  • soliddb_backup_block_size

    This variable sets the backup copy block size.

  • soliddb_backupdir

    This variable sets the backup copy directory.

  • soliddb_cache_size

    This variable sets the server's database cache memory size in bytes; the minimum size is 512 kilobytes. Although solidDB for MySQL is able to run with a small cache size, a larger cache size speeds up the server. The cache size needed depends on the database file-size, the number of connected users, and the nature of the operations executed against the server.

    [Warning]Warning

    Setting the cache size to a value larger than the amount of memory available may significantly degrade performance. If your system only has a small amount of free memory available, reduce the cache size.

  • soliddb_filespec=database_file1 size[,database_file2 size2 ...]

    This variable defines the location and the maximum size of the index file. Note that in solidDB, the term “index file” is used as a synonym for “database file”. The parameter accepts the following two arguments: database filename followed with maximum size of the database file, for example:

    soliddb_filespec=c:\soldb\solid.db 20M
    

    [Note]Note

    You cannot use space “ ” or comma “,” characters on your path and filenames.

    For more information on adding more database files while the server is running, see Chapter 28, solidDB File Space Management and Disk I/O.

  • soliddb_durability_level

    This parameter controls whether the transaction durability level is “strict” or “relaxed”. If durability is “strict”, writes to the transaction log are synchronous. As soon as a transaction has been committed, the transaction is written to the transaction log. If durability is “relaxed”, writes are asynchronous, which means that there can be a delay between the time that the transaction is committed and the time that it is logged. For more information on the effect of this parameter, see Chapter 16, Transaction Durability.

    The possible values are:

    • 1, relaxed durability

    • 3, strict durability

    Value 2, adaptive durability, is not supported in solidDB for MySQL. Adaptive durability is a configuration setting for solidDB Storage Engine that can only be used in Solid EmbeddedEngine™ and BoostEngine™ products. If you specify an unsupported value, the default value 3 is used.

  • soliddb_logdir

    To ensure the durability of committed transactions, transaction results are written immediately to a file in a specified directory when the transaction is committed. This file must be stored to a local drive using local disk names to avoid problems with network input/output (I/O) and to achieve better performance. The default log file directory is the MySQL data directory. The soliddb_logdir parameter defines a path for the transaction log files. For example, the following setting:

    soliddb_logdir = d:\logdir\
    

    instructs solidDB for MySQL to create log files to directory d:\logdir and names them sequentially starting from sol00001.log.

    [Tip]Tip

    Placing log files on a physical disk separate from the database files improves performance.

  • soliddb_lock_wait_timeout

    This variable sets the timeout in seconds a solidDB transaction waits for a lock before being rolled back. solidDB automatically detects transaction deadlocks in its own lock table and rolls back the transaction. The default value is 50 seconds.

  • soliddb_log_block_size

    This variable sets the log block size.

  • soliddb_db_block_size

    This variable sets the database file block size.

    [Note]Note

    The block size has only effect when the database is created. If you change the block size after you have created the first database, the change will not have effect on the new databases you create, but the same value is used for all database files. If the given block size value differs from the original soliddb_db_block_size size, the soliddb_db_block_size is used and a warning is displayed.

  • soliddb_io_threads

    This variable sets the number of helper I/O threads (for each I/O device) for read and write. You can restrict the number of write threads with the soliddb_write_threads parameter.

  • soliddb_checkpoint_time

    This variable specifies the minimum time in seconds between two checkpoint operations.

  • soliddb_write_threads

    This parameter sets the number of helper threads dedicated to a writing task (for each I/O device). You must define soliddb_io_threads for this parameter to take effect.

  • soliddb_pessimistic

    When you specify PESSIMISTIC concurrency control, the server places locks on rows to control the level of consistency and concurrency when users are submitting queries or updates to the database table rows. The default value is true, that is, the server uses pessimistic concurrency control. However, by setting this parameter to false, you can instruct the server to default to optimistic locking.

    Setting concurrency control to OPTIMISTIC only affects tables created after the setting change. You cannot change the concurrency control behavior for an existing table.

    For more information, see Chapter 21, Concurrency Control

  • soliddb_readahead

    This variable sets the number of prefetched index reads during long sequential searches. Note that when the I/O manager is handling a long sequential search, it enters a read-ahead operation mode. This mode ensures that the next file blocks of the search are read into the cache in advance. This naturally improves the overall performance of sequential searches.

  • soliddb_checkpoint_interval

    This variable sets the number of writes to the log files that cause automatic checkpoint creation. A large setting can delay checkpoints and make then larger. A small setting will guarantee a small checkpoint size.

  • soliddb_extend_increment

    This variable sets the number of disk space blocks that are allocated at a time when solidDB allocates more space for the database file.

  • soliddb_lockhash_size

    The server uses a hash table (array) to store lock information. If the array size is remarkably underestimated, the server performance degrades. A too large hash table does not affect directly to the performance, although it causes memory overhead.

Chapter 10. solidDB Data Dictionary

Data dictionary is a file that defines the basic organization of a database. A data dictionary contains a list of all files in the database, the number of records in each file, and the names and types of each field.

10.1 solidDB Data Dictionary Installation

Data dictionary is a file that defines the basic organization of a database. A data dictionary contains a list of all files in the database, the number of records in each file, and the names and types of each field. From MySQL 5.1, solidDB data dictionary is provided as a extension of INFORMATION_SCHEMA tables using MySQL:s Pluggable Storage Engine API.

You can install solidDB data dictionary to database by issuing the following commands in the MySQL client interface:

install plugin SOLIDDB_SYS_TABLES soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_COLUMNS soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_COLUMNS_AUX soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_KEYS soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_KEYPARTS soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_KEYPARTS_AUX soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_FORKEYS soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_FORKEYPARTS soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_SCHEMAS soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_SEQUENCES soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_CARDINAL soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_TABLEMODES soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_COLLATIONS soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_INFO soname 'libsoliddb.so';
install plugin SOLIDDB_SYS_BLOBS soname 'libsoliddb.so';

10.2 Using solidDB Data Dictionary

You can use solidDB Data Dictionary as shown in the example below:

select * from information_schema.SOLIDDB_SYS_TABLES;

10.3 Removing solidDB Data Dictionary

You can remove solidDB data dictionary from database soliddb by issuing the following commands in the MySQL client interface:

uninstall plugin SOLIDDB_SYS_TABLES;
uninstall plugin SOLIDDB_SYS_COLUMNS;
uninstall plugin SOLIDDB_SYS_COLUMNS_AUX;
uninstall plugin SOLIDDB_SYS_KEYS;
uninstall plugin SOLIDDB_SYS_KEYPARTS;
uninstall plugin SOLIDDB_SYS_KEYPARTS_AUX;
uninstall plugin SOLIDDB_SYS_FORKEYS;
uninstall plugin SOLIDDB_SYS_FORKEYPARTS;
uninstall plugin SOLIDDB_SYS_SCHEMAS;
uninstall plugin SOLIDDB_SYS_SEQUENCES;
uninstall plugin SOLIDDB_SYS_CARDINAL;
uninstall plugin SOLIDDB_SYS_TABLEMODES;
uninstall plugin SOLIDDB_SYS_COLLATIONS;
uninstall plugin SOLIDDB_SYS_INFO;
uninstall plugin SOLIDDB_SYS_BLOBS;
    

10.4 Accessing solidDB Data Dictionary

solidDB data dictionary stores server information. Your ability to access specific system tables depends on your user access rights. For example, Database Administrators (DBA) can view all information on the data dictionary. solidDB data dictionary contains the following tables:

TableDescription
SOLIDDB_SYS_TABLES This table includes information about tables. See also Section 10.5.2, “SOLIDDB_SYS_TABLES”.
SOLIDDB_SYS_COLUMNS This table includes information about columns. See also Section 10.5.3, “SOLIDDB_SYS_COLUMNS”.
SOLIDDB_SYS_COLUMNS_AUX This table includes information about columns default values. See also Section 10.5.4, “SOLIDDB_SYS_COLUMNS_AUX”.
SOLIDDB_SYS_KEYS This table includes information about keys. See also Section 10.5.5, “SOLIDDB_SYS_KEYS”.
SOLIDDB_SYS_KEYPARTS This table includes information about key attributes. See also Section 10.5.6, “SOLIDDB_SYS_KEYPARTS”.
SOLIDDB_SYS_KEYPARTS_AUX This table includes information about the directory prefix length. See also Section 10.5.7, “SOLIDDB_SYS_KEYPARTS_AUX”.
SOLIDDB_SYS_FORKEYS This table includes information about foreign keys. See also Section 10.5.8, “SOLIDDB_SYS_FORKEYS”.
SOLIDDB_SYS_FORKEYPARTS This table includes information about foreign key attributes. See also Section 10.5.9, “SOLIDDB_SYS_FORKEYPARTS”.
SOLIDDB_SYS_SCHEMAS This table includes information about schemas (databases). See also Section 10.5.10, “SOLIDDB_SYS_SCHEMAS”.
SOLIDDB_SYS_SEQUENCES This table includes information about sequences (autoincrement fields are implemented using sequences). See also Section 10.5.11, “SOLIDDB_SYS_SEQUENCES”.
SOLIDDB_SYS_BLOBS This table includes information about the blobs stored into the database. Furthermore, this table sees to it that the BLOB is physically saved on disk once only even if it is logically saved several times. See also Section 10.5.12, “SOLIDDB_SYS_BLOBS”.
SOLIDDB_SYS_CARDINAL This table includes information about the number of rows in the table and the size of the data in the table. See also Section 10.5.13, “SOLIDDB_SYS_CARDINAL”.
SOLIDDB_SYS_INFO This table includes system information. See also Section 10.5.14, “SOLIDDB_SYS_INFO”.
SOLIDDB_SYS_TABLEMODES This table shows the table mode of the tables whose table mode was explicitly set. It does not show the mode of tables that were left at the default mode (pessimistic). See also Section 10.5.15, “SOLIDDB_SYS_TABLEMODES”.
SOLIDDB_SYS_COLLATIONS This table contains information on the supported charsets and collations. See also Section 10.5.16, “SOLIDDB_SYS_COLLATIONS”.

For example, if you have created a solidDB table t01 using MySQL client as follows:

mysql> use test;

Database changed
    

mysql> create table t01(a int not null, primary key(a)) engine=soliddb;

Query OK, 0 rows affected (0.73 sec)
    

Assuming that you have installed solidDB data dictionary to database soliddb, you can see a description of all solidDB tables by issuing the following command in the MySQL client interface:

mysql> select * from soliddb.SOLIDDB_SYS_TABLES;

+-------+-------------------------+------------+--------------+
| ID    | TABLE_NAME              | TABLE_TYPE | TABLE_SCHEMA |
+-------+-------------------------+------------+--------------+
|   100 | SYS_TABLES              | BASE TABLE | _SYSTEM      |
|   200 | SYS_COLUMNS             | BASE TABLE | _SYSTEM      |
|   400 | SYS_UROLE               | BASE TABLE | _SYSTEM      |
|   500 | SYS_RELAUTH             | BASE TABLE | _SYSTEM      |
|   600 | SYS_ATTAUTH             | BASE TABLE | _SYSTEM      |
|   700 | SYS_VIEWS               | BASE TABLE | _SYSTEM      |
|   800 | SYS_KEYPARTS            | BASE TABLE | _SYSTEM      |
|   900 | SYS_KEYS                | BASE TABLE | _SYSTEM      |
|  1000 | SYS_CARDINAL            | BASE TABLE | _SYSTEM      |
|  1100 | SYS_INFO                | BASE TABLE | _SYSTEM      |
|  1300 | SYS_SYNONYM             | BASE TABLE | _SYSTEM      |
|  8000 | SYS_USERS               | BASE TABLE | _SYSTEM      |
|  8002 | SQL_LANGUAGES           | BASE TABLE | _SYSTEM      |
|  8004 | SYS_TYPES               | BASE TABLE | _SYSTEM      |
|  8006 | SYS_BLOBS               | BASE TABLE | _SYSTEM      |
|  8010 | SYS_FORKEYS             | BASE TABLE | _SYSTEM      |
|  8013 | SYS_FORKEYPARTS         | BASE TABLE | _SYSTEM      |
|  8015 | SYS_CHECKSTRINGS        | BASE TABLE | _SYSTEM      |
|  8017 | SYS_PROCEDURES          | BASE TABLE | _SYSTEM      |
|  8020 | SYS_TRIGGERS            | BASE TABLE | _SYSTEM      |
|  8024 | SYS_TABLEMODES          | BASE TABLE | _SYSTEM      |
|  8026 | SYS_EVENTS              | BASE TABLE | _SYSTEM      |
|  8029 | SYS_CATALOGS            | BASE TABLE | _SYSTEM      |
|  8032 | SYS_SCHEMAS             | BASE TABLE | _SYSTEM      |
|  8035 | SYS_SEQUENCES           | BASE TABLE | _SYSTEM      |
|  8038 | SYS_PROPERTIES          | BASE TABLE | _SYSTEM      |
|  8040 | SYS_HOTSTANDBY          | BASE TABLE | _SYSTEM      |
|  8043 | SYS_COLUMNS_AUX         | BASE TABLE | _SYSTEM      |
|  8045 | SYS_COLLATIONS          | BASE TABLE | _SYSTEM      |
| 10000 | SOLIDDB_SYS_TABLES      | BASE TABLE | soliddb      |
| 10002 | SOLIDDB_SYS_COLUMNS     | BASE TABLE | soliddb      |
| 10002 | SOLIDDB_SYS_COLUMNS_AUX | BASE TABLE | soliddb      |
| 10004 | SOLIDDB_SYS_KEYS        | BASE TABLE | soliddb      |
| 10006 | SOLIDDB_SYS_KEYPARTS    | BASE TABLE | soliddb      |
| 10007 | SOLIDDB_SYS_KEYPARTS_AUX| BASE TABLE | soliddb      |
| 10008 | SOLIDDB_SYS_FORKEYS     | BASE TABLE | soliddb      |
| 10010 | SOLIDDB_SYS_FORKEYPARTS | BASE TABLE | soliddb      |
| 10012 | SOLIDDB_SYS_SCHEMAS     | BASE TABLE | soliddb      |
| 10014 | SOLIDDB_SYS_SEQUENCES   | BASE TABLE | soliddb      |
| 10017 | SOLIDDB_SYS_BLOBS       | BASE TABLE | soliddb      |
| 10019 | SOLIDDB_SYS_CARDINAL    | BASE TABLE | soliddb      |
| 10021 | SOLIDDB_SYS_INFO        | BASE TABLE | soliddb      |
| 10023 | SOLIDDB_SYS_TABLEMODES  | BASE TABLE | soliddb      |
| 10025 | SOLIDDB_ADMIN_COMMANDS  | BASE TABLE | soliddb      |
| 10025 | SOLIDDB_SYS_COLLATIONS  | BASE TABLE | soliddb      |
+-------+-------------------------+------------+--------------+
48 rows in set (0.02 sec)
    
[Note]Note

All tables beginning with SYS_ or SQL_ are solidDB internal tables and cannot be accessed from the MySQL client.

10.5 solidDB Data Dictionary Contents

This chapter explains the contents of the solidDB system tables.

10.5.1 SOLIDDB_ADMIN_COMMANDS

You can add ADMIN commands to this system table.

Column nameData typeDescription
COMMAND VARCHAR(255) The command to be added to the table.
PARAMETERS VARCHAR(1024) NULL The command parameters to be added to the table.

10.5.2 SOLIDDB_SYS_TABLES

This table lists all the system tables.

There are no restrictions for viewing the system tables, which means even users with no access rights can view them. However, specific users are restricted from viewing the user table information. Owners are restricted to viewing user tables they have created and users can only view tables to which they have INSERT, UPDATE, DELETE, or SELECT access. Users are restricted from viewing any user tables if they have no access rights. No restrictions apply to DBAs.

Column nameData typeDescription
ID INTEGER NOT NULL Unique table identifier.
TABLE_NAME VARCHAR(254) UNICODE The name of the table.
TABLE_TYPE VARCHAR(254) UNICODE The type of the table (BASE TABLE or VIEW).
TABLE_SCHEMA VARCHAR(254) UNICODE The name of the schema containing TABLE_NAME.
TABLE_CATALOG VARCHAR(254) UNICODE The name of the catalog containing TABLE_NAME.
CREATIME TIMESTAMP The creation time of the table.
CHECKSTRING LONG VARCHAR UNICODE Possible check option defined for the table.
REMARKS LONG VARCHAR UNICODE Reserved for future use.

10.5.3 SOLIDDB_SYS_COLUMNS

This table lists all system table columns.

There are no owner or user viewing restrictions for viewing the system columns, which means owners can view columns other than those they have created in this table and users with no access rights or with specific access rights can still view any system column in this table.

Column nameData typeDescription
ID INTEGER NOT NULL Unique column identifier.
REL_ID INTEGER NOT NULL The relation identifier as in SYS_TABLES.
COLUMN_NAME VARCHAR(254) UNICODE The name of the column.
COLUMN_NUMBER INTEGER NOT NULL The number of the column in the table (in creation order).
DATA_TYPE VARCHAR(254) UNICODE The data type of the column.
SQL_DATA_TYPE_NUM SMALLINT ODBC compliant data type number.
DATA_TYPE_NUMBER INTEGER Internal data type number.
CHAR_MAX_LENGTH INTEGER Maximum length for a CHAR field.
NUMERIC_PRECISION INTEGER Numeric precision.
NUMERIC_PREC_RADIX SMALLINT Numeric precision radix.
NUMERIC_SCALE SMALLINT Numeric scale.
NULLABLE CHAR(3) UNICODE Are NULL values allowed (Yes, No).
NULLABLE_ODBC SMALLINT NOT NULL ODBC, are NULL values allowed (1,0).
FORMAT VARCHAR(254) UNICODE Reserved for future use.
DEFAULT_VAL VARBINARY(254) Current default value (if set).
ATTR_TYPE INTEGER User defined (0) or internal (>0).
REMARKS LONG VARCHAR UNICODE Reserved for future use.

10.5.4 SOLIDDB_SYS_COLUMNS_AUX

If you insert a column with a default value to a table that has existing rows, the column default value is not appended to the existing rows. Instead, the default value defined in the column insert statement is written to the SYS_COLUMNS_AUX table. If an SQL query is targeted at a row that was inserted to the table before the column, the column value is read from the SYS_COLUMNS_AUX table unless the new column value on the row has been changed after it was inserted. Only the original default value is saved in the SYS_COLUMNS_AUX table. The field's external collation is also saved in this table.

Column nameData typeDescription
ID INTEGER NOT NULL Unique column identifier.
ORIGINAL_DEFAULT VARBINARY(254) This field indicates the original default value.
AUTO_INC_SEQ_ID INTEGER This field indicates the autoincrementation sequence ID.
EXTERNAL_DATA_TYPE INTEGER This field indicates the field's external data type.
EXTERNAL_COLLATION VARBINARY(254) UNICODE This field indicates the field's external collation.

10.5.5 SOLIDDB_SYS_KEYS

All database tables must have one clustering key. This key defines the physical sorting order of the data. It has no capacity impact. If a primary key is defined, the primary key is used as the clustering key. If no primary key is defined, an entry with key name $CLUSTKEY_xxxxx will be automatically created in SYS_KEYS.

If there is a primary key definition for the table, there will be an entry in SYS_KEYS with a key_name like $PRIMARYKEY_xxxx for this entry. The key_primary and key_clustering columns will have value YES.

If there is no primary key definition for the table, there will be an entry in SYS_KEYS with a key_name like $CLUSTKEY_xxxxx. The key_primary column will have value NO and the key_clustering column will have value YES.

Column nameData typeDescription
ID INTEGER NOT NULL Unique key identifier.
REL_ID INTEGER NOT NULL The relation identifier as in SYS_TABLES.
KEY_NAME VARCHAR(254) UNICODE The name of the key.
KEY_UNIQUE CHAR(3) UNICODE Is the key unique (Yes, No).
KEY_NONUNIQUE_ODBC SMALLINT NOT NULL ODBC, is the key NOT unique (1, 0).
KEY_CLUSTERING CHAR(3) UNICODE NOT NULL Is the key a clustering key (Yes, No).
KEY_PRIMARY CHAR(3) UNICODE NOT NULL Is the key a primary key (Yes, No).
KEY_PREJOINED CHAR(3) UNICODE NOT NULL Reserved for future use.
KEY_SCHEMA VARCHAR(254) UNICODE NOT NULL The owner of the key.
KEY_NREF INTEGER NOT NULL When creating a primary key, the server uses ALL fields of the table, even if the user specified N fields (the N fields specified by the user become the first N fields of the key). KEY_NREF = N, that is, the number of fields specified by the user.
KEY_CATALOG VARCHAR(254) UNICODE Creator name or the owner of the key.

10.5.6 SOLIDDB_SYS_KEYPARTS

Column nameData typeDescription
ID INTEGER NOT NULL This column is a foreign key reference to sys_keys.id, so that you can determine which key each keypart is part of.
REL_ID INTEGER NOT NULL The relation identifier as in SYS_TABLES.
KEYP_NO INTEGER NOT NULL Keypart identifier.
ATTR_ID INTEGER Column identifier.
ATTR_NO INTEGER The number of the column in the table (in creation order).
ATTR_TYPE INTEGER The type of the column.
CONST_VALUE VARBINARY(254) Constant value or NULL.
ASCENDING CHAR(3) UNICODE NOT NULL Is the key ascending (Yes) or descending (No).

10.5.7 SOLIDDB_SYS_KEYPARTS_AUX

Column nameData typeDescription
ID INTEGER NOT NULL This column is a foreign key reference to sys_keys.id, so that you can determine which key each keypart is part of.
KEYP_NO INTEGER NOT NULL Keypart identifier.
PREFIX_LENGTH INTEGER The prefix length.

10.5.8 SOLIDDB_SYS_FORKEYS

Column nameData typeDescription
ID INTEGER NOT NULL Foreign key identifier.
REF_REL_ID INTEGER NOT NULL Referenced table identifier.
CREATE_REL_ID INTEGER NOT NULL Creator table identifier.
REF_KEY_ID INTEGER NOT NULL Referenced key identifier.
REF_TYPE INTEGER NOT NULL Reference type.
KEY_SCHEMA VARCHAR(254) UNICODE Creator name.
KEY_CATALOG VARCHAR(254) UNICODE NOT NULL Creator name or the owner of the key.
KEY_NREF INTEGER NOT NULL Number of referenced key parts.

10.5.9 SOLIDDB_SYS_FORKEYPARTS

Column nameData typeDescription
ID INTEGER NOT NULL Foreign key identifier.
KEYP_NO INTEGER NOT NULL Keypart number.
ATTR_NO INTEGER NOT NULL Column number.
ATTR_ID INTEGER NOT NULL Column identifier.
ATTR_TYPE INTEGER NOT NULL Column type.
CONST_VALUE VARBINARY(254) Possible internal constant value; otherwise NULL.
PREFIX_LENGTH INTEGER This column indicates the directory prefix length.

10.5.10 SOLIDDB_SYS_SCHEMAS

SYS_SCHEMAS lists available schemas.

Column nameData typeDescription
ID INTEGER NOT NULL Schema identifier.
NAME VARCHAR(254) UNICODE NOT NULL Schema name.
OWNER VARCHAR(254) UNICODE NOT NULL Schema owner name.
CREATIME TIMESTAMP NOT NULL Create date and time.
SCHEMA_CATALOG VARCHAR(254) UNICODE Schema catalog.

10.5.11 SOLIDDB_SYS_SEQUENCES

Column nameData typeDescription
SEQUENCE_NAME VARCHAR(254) UNICODE NOT NULL Sequence name.
ID INTEGER NOT NULL Unique identifier.
DENSE VARCHAR(3) UNICODE NOT NULL Is the sequence dense or sparse.
SEQUENCE_SCHEMA VARCHAR(254) UNICODE NOT NULL The name of the schema containing SEQUENCE_NAME.
SEQUENCE_CATALOG VARCHAR(254) UNICODE NOT NULL The name of the catalog containing SEQUENCE_NAME.
CREATIME TIMESTAMP Creation time.

10.5.12 SOLIDDB_SYS_BLOBS

Column nameData typeDescription
ID BIGINT Blob identifier.
STARTPOS BIGINT Byte offset from the beginning of the blob — the start position of the pages.
ENDSIZE BIGINT Byte offset of the end of the last page +1.
TOTALSIZE BIGINT Total size of the blob.
REFCOUNT INTEGER The number of references, that is, the number of existing instances of the same blob.
COMPLETE INTEGER Indicates whether the write to the blob is ready or not.
STARTCPNUM INTEGER Indicates on what checkpoint level the writing of the blob started.
NUMPAGES INTEGER The number of pages the blob consists of.

10.5.13 SOLIDDB_SYS_CARDINAL

Column nameData typeDescription
REL_ID INTEGER The relation identifier as in SYS_TABLES.
CARDIN INTEGER The number of rows in the table.
SIZE INTEGER The size of the data in the table.
LAST_UPD TIMESTAMP The timestamp of the last update in the table.

10.5.14 SOLIDDB_SYS_INFO

Column nameData typeDescription
PROPERTY WVARCHAR The name of the property.
VALUE_STR WVARCHAR Value as a string.
VALUE_INT INTEGER Value as an integer.

10.5.15 SOLIDDB_SYS_TABLEMODES

Column nameData typeDescription
ID INTEGER Relation identifier.
MODE WVARCHAR Concurrency control mode.
MODIFY_TIME TIMESTAMP Last modify time.
MODIFY_USER WVARCHAR Last user that modified.

10.5.16 SOLIDDB_SYS_COLLATIONS

Column nameData typeDescription
ID INTEGER NOT NULL Unique collation identifier.
CHARSET_NAME VARCHAR(254) UNICODE NOT NULL Charset name.
COLLATION_NAME VARCHAR(254) UNICODE NOT NULL Collation name.
REMARKS VARCHAR(254) UNICODE Remarks on the collation.

Chapter 11. Creating and Using solidDB Tables

To create a solidDB table, specify the ENGINE = solidDB option in the CREATE TABLE statement:

CREATE TABLE customers (a INT, b CHAR (20), INDEX (a)) ENGINE=solidDB;

The statement mentioned previously creates a table and an index on column a in the solidDB database that consists of the data files that you specified in the .my.cnf file. In addition, solidDB for MySQL creates a customers.frm file in the test directory under the MySQL database directory. Internally, solidDB for MySQL adds an entry for the table to its own data dictionary. The entry includes the database name. For example, if you have a database named test, and you create a table called customers in it, the entry is for 'test/customers'. This means you can create a table of the same name (customers) in another database, and the table names do not collide inside solidDB for MySQL.

You can specify the table type, optimistic or pessimistic, when you create the table. For more information on table modes, see Chapter 21, Concurrency Control. To create an optimistic table, you can use, for example, the command below:

CREATE TABLE customers (a INT, b CHAR (20), INDEX (a)) ENGINE=solidDB COMMENT='MODE=OPTIMISTIC';

To create a pessimistic table, you can use, for example, the command below:

CREATE TABLE customers (a INT, b CHAR (20), INDEX (a)) ENGINE=solidDB COMMENT='MODE=PESSIMISTIC';

If you specify no table type, the default value PESSIMISTIC is used.

If you want all your (non-system) tables to be created as solidDB tables, you can simply add the line default-storage-engine=soliddb to the [mysqld] section of your server option file.

You can check the table type for an existing table by two methods:

  • If the solidDB system tables are created, you can issue the query below:

    SELECT MODE FROM SOLIDDB_SYS_TABLEMODES, SOLIDDB_SYS_TABLES
     -> WHERE SOLIDDB_SYS_TABLES.TABLE_NAME = 't1' AND
     -> SOLIDDB_SYS_TABLES.ID = SOLIDDB_SYS_TABLEMODES.ID;
            

    The result is such as follows:

    +-------------+
    | MODE        |
    +-------------+
    | OPTIMISTIC  | 
    +-------------+
    1 row in set (0.01 sec)
            

  • If you have given the table type in the create command, you can use the query below:

    mysql> show create table t1\g

    The result is such as follows:

    +-------+----------------------------------------------------------+
    | Table | Create Table                                             |
    +-------+----------------------------------------------------------+
    | t1    | CREATE TABLE 't1' (                                      |
    |       |'a' int(11) NOT NULL,                                     |
    |       |PRIMARY KEY  ('a')                                        |
    |       |) ENGINE=solidDB DEFAULT CHARSET=latin1                   |
    |       |COMMENT='MODE=OPTIMISTIC'                                 |
    +-------+----------------------------------------------------------+
    1 row in set (0.02 sec)
            

    [Note]Note

    The output has been modified for layout purposes.

Chapter 12. Character Sets and Collations

A character set is a set of symbols and encodings. A collation is a set of rules for comparing characters in a character set.

Here is an example of an imaginary character set:

Let's assume that have an alphabet with four letters: 'A', 'B', 'a', 'b'. We match each letter with a number: 'A' = 0, 'B' = 1, 'a' = 2, 'b' = 3. The letter 'A' is a symbol, the number 0 is the encoding for 'A', and the combination of all four letters and their encodings is a character set. Now we want to compare two string values, 'A' and 'B', for example. We can do this by looking at the encodings: 0 for 'A' and 1 for 'B'. Since 0 is less than 1, we conclude that 'A' is less than 'B'.

solidDB for MySQL 5.1 only supports a limited number of collations and character sets. The number of supported collations and character sets will be extended in the following releases.

By default, solidDB for MySQL 5.1 uses the latin1 character set and the latin1_swedish_c1 collation.

The available character sets can be printed by using the SHOW CHARACTER SET statement:

mysql> SHOW CHARACTER SET;

[Note]Note

If you use the \g option in the SHOW CHARACTER SET statement to show collations, do not use the semicolon at the end of the statement. For example:

mysql> SHOW CHARACTER SET tl \g

Available collations in MySQL can be printed by using the SHOW COLLATION statement:

mysql> SHOW COLLATION;

Note that this printout includes all collations and character sets that are supported by MySQL. solidDB for MySQL 5.1 does not support all these yet. For more information about collations and which collations MySQL supports, please refer to MySQL User Guide Chapter 10.

solidDB for MySQL 5.1 currently supports part of the latin1, utf8, ucs2, cp932 and eucjpms character sets with the following collations. The table is sorted by charset and the collations within each charset are in alphabetical order.

CollationCharsetMySQL IDDefaultDescription
binary binary

63

No

Binary collation

cp932_japanese_ci cp932

95

No

SJIS for Windows Japanese

eucjpms_japanese_ci eucjpms

97

No

UJIS for Windows Japanese

latin1_bin latin1

47

No

Binary according to latin1 encoding

latin1_danish_ci latin1

15

No

Danish/Norwegian

latin1_general_ci latin1

48

No

Multilingual (Western European)

latin1_general_cs latin1

49

No

Multilingual (ISO Western European), case sensitive

latin1_german1_ci latin1

5

No

German DIN-1

latin1_german2_ci latin1

31

No

German DIN-2

latin1_spanish_ci latin1

94

No

Spanish

latin1_swedish_ci latin1

8

Yes

Swedish/Finnish

ucs2_bin ucs2

90

No

Binary according to ucs2 encoding

ucs2_czech_ci ucs2

138

No

Czech according to ucs2 encoding

ucs2_danish_ci ucs2

139

No

Danish according to ucs2 encoding

ucs2_esperanto_ci ucs2

145

No

Esperanto according to ucs2 encoding

ucs2_estonian_ci ucs2

134

No

Estonian according to ucs2 encoding

ucs2_general_ci ucs2

35

No

Multilingual (Western European) according to ucs2 encoding

ucs2_hungarian_ci ucs2

146

No

Hungarian according to ucs2 encoding

ucs2_icelandic_ci ucs2

129

No

Icelandic according to ucs2 encoding

ucs2_latvian_ci ucs2

130

No

Latvian according to ucs2 encoding

ucs2_lithuanian_ci ucs2

140

No

Lithuanian according to ucs2 encoding

ucs2_persian_ci ucs2

144

No

Persian according to ucs2 encoding

ucs2_polish_ci ucs2

133

No

Polish according to ucs2 encoding

ucs2_roman_ci ucs2

143

No

West European

ucs2_romanian_ci ucs2

131

No

Romanian according to ucs2 encoding

ucs2_slovak_ci ucs2

141

No

Slovak according to ucs2 encoding

ucs2_slovenian_ci ucs2

132

No

Slovenian according to ucs2 encoding

ucs2_spanish_ci ucs2

135

No

Spanish according to ucs2 encoding

ucs2_spanish2_ci ucs2

142

No

Traditional Spanish according to ucs2 encoding

ucs2_swedish_ci ucs2

136

No

Swedish/Finnish according to ucs2 encoding

ucs2_turkish_ci ucs2

137

No

Turkish according to ucs2 encoding

ucs2_unicode_ci ucs2

128

No

Unicode ucs2

utf8_bin utf8

83

No

Binary according to utf8 encoding

utf8_czech_ci utf8

202

No

Czech according to utf8 encoding

utf8_danish_ci utf8

203

No

Danish according to utf8 encoding

utf8_esperanto_ci utf8

209

No

Esperanto according to utf8 encoding

utf8_estonian_ci utf8

198

No

Estonian according to utf8 encoding

utf8_general_ci utf8

33

No

Multilingual (Western European) according to utf8 encoding

utf8_hungarian_ci utf8

210

No

Hungarian according to utf8 encoding

utf8_icelandic_ci utf8

193

No

Icelandic according to utf8 encoding

utf8_latvian_ci utf8

194

No

Latvian according to utf8 encoding

utf8_lithuanian_ci utf8

204

No

Lithuanian according to utf8 encoding

utf8_persian_ci utf8

208

No

Persian according to utf8 encoding

utf8_polish_ci utf8

197

No

Polish according to utf8 encoding

utf8_roman_ci utf8

207

No

West European

utf8_romanian_ci utf8

195

No

Romanian according to utf8 encoding

utf8_slovak_ci utf8

205

No

Slovak according to utf8 encoding

utf8_slovenian_ci utf8

196

No

Slovenian according to utf8 encoding

utf8_spanish_ci utf8

199

No

Spanish according to utf8 encoding

utf8_spanish2_ci utf8

206

No

Traditional Spanish according to utf8 encoding

utf8_swedish_ci utf8

200

No

Swedish/Finnish according to utf8 encoding

utf8_turkish_ci utf8

201

No

Turkish according to utf8 encoding

utf8_unicode_ci utf8

192

No

Unicode utf8

If the solidDB system tables are installed, the supported collations in solidDB for MySQL can be printed by selecting the contents of the SOLIDDB_SYS_COLLATIONS table:

mysql> select ID, CHARSET_NAME, COLLATION_NAME FROM SOLIDDB_SYS_COLLATIONS order by ID;

If the solidDB system tables are installed, the supported charsets in solidDB for MySQL can be printed by selecting the CHARSET_NAME from SOLIDDB_SYS_COLLATIONS table:

mysql> mysql> select distinct CHARSET_NAME from SOLIDDB_SYS_COLLATIONS;

The supported charsets are:

+--------------+
| CHARSET_NAME |
+--------------+
| latin1       | 
| utf8         | 
| ucs2         | 
| binary       | 
| cp932        | 
| eucjpms      | 
+--------------+
    

where:

NameDescription
latin1

cp1252 West European

utf8

UTF-8 Unicode

ucs2

UCS-2 Unicode

binary

Binary pseudo charset

cp932

SJIS for Windows Japanese

eucjpms

UJIS for Windows Japanese

Chapter 13. Limitations on solidDB Tables in This Release

There are a number of known issues with solidDB tables in this release. Solid is already working to address the most serious of these. Known issues:

  • This beta release does not support backup functions.

  • This beta release does not support row based replication to tables that do not contain either a primary key or at least one unique key.

  • INSERT DELAYED ... is not supported. An attempt to use it leads to an error as follows:

    mysql> insert delayed into isd values (1);
    ERROR 1031 (HY000): Table storage engine for 'isd' doesn't have this option
                

  • Ordering of full 32-bit and 64-bit unsigned integer types may not be correct. This is a known error, which could not be fixed on time for the release.

  • BLOB support optimizations are not implemented; memory usage optimizations are needed.

  • Table and column names are limited to 255 bytes.

  • Partial backups are not supported in this release.

  • Point in time recovery is not supported in this release.

  • Although solidDB internally supports row sizes larger than 65535, you cannot define a row containing VARCHAR columns with a combined size larger than 65535. If you try, you get error 1118. For more information, see Chapter 29, solidDB Error Handling.

  • solidDB tables do not support FULLTEXT indexes.

  • solidDB tables do not support spatial indexes.

  • This version of solidDB for MySQL does not support referential action SET DEFAULT.

  • The database can hold up to 232 objects, that is, tables, procedures, triggers, indexes, and so on. The same counter (unsigned integer) is used to get IDs for all.

  • The table column limit is 1000. Trying to create a table with more than 1000 columns returns error 13121. For more information, see Chapter 29, solidDB Error Handling.

  • Server-side cursors are not supported on solidDB.

  • X/Open XA protocol is not supported on solidDB.

  • Backup is not supported on solidDB.

  • LOAD INDEX is not implemented on solidDB.

  • SAVEPOINT is not implemented on solidDB.

  • [Warning]Warning

    Do not convert MySQL system tables in the mysql database from MyISAM to solidDB tables. This is an unsupported operation. If you do this, solidDB for MySQL does not restart until you restore the old system tables from a backup or re-generate them with the mysql_install_db script.

Chapter 14. Dynamic Configuration Settings

Some solidDB system variables are dynamic and can be set at runtime using SET GLOBAL. You can also obtain their values using SELECT. See Using System Variables in MySQL documentation for more information.

The following chapters describe the dynamic solidDB system variables. The options that can be set with the SET statement are also included. Section SET Syntax discusses these options.

Variables that have a type of 'string' take a string value. Variables that have a type of 'numeric' take a numeric value.

Consider, for example, a situation where your database has reached the maximum size specified by soliddb_filespec. You can add a new database file dynamically using a MySQL client as follows:

shell> mysql
shell> SET GLOBAL soliddb_filespec='solid5.db 1G';
shell> exit;

You can only add one database file at a time. If you need to add more than one database file, you must set soliddb_filespec several times.

14.1 soliddb_admin_command

The parameter value type is string.

This parameter can have the values explained in the following list. For each value the purpose, syntax, and an example are provided.

  • backup

    This parameter is used to take backups. The syntax is shown below:

    'backup [directory]'
              

    An example command is shown below:

    mysql> SET GLOBAL soliddb_admin_command='backup';

    An example command with the optional backup directory for Linux is shown below:

    mysql> SET GLOBAL soliddb_admin_command='backup /backup/';

  • checkpoint

    This parameter is used to make a checkpoint. The syntax is shown below:

    'checkpoint'
              

    An example command is shown below:

    mysql> SET GLOBAL soliddb_admin_command='checkpoint';

  • pmon

    This parameter is used to start or stop performance monitoring. The syntax is shown below:

    'pmon diff {start <file> <interval> [append] | stop}'
              

    The command to start performance monitoring is shown below:

    mysql> SET GLOBAL soliddb_admin_command='pmon diff start pmon.out 1000';

    The command to stop performance monitoring is shown below:

    mysql> SET GLOBAL soliddb_admin_command='pmon diff stop';

14.2 soliddb_backupdir

This parameter defines the backup directory.

The parameter value type is string.

14.3 soliddb_filespec

This parameter adds a new database file.

The parameter value type is string.

14.4 soliddb_durability_level

This parameter sets the transaction durability level.

The parameter value type is numeric 1-3.

14.5 soliddb_checkpoint_time

This parameter sets the checkpoint time interval.

The parameter value type is numeric.

14.6 soliddb_lock_wait_timeout

This parameter sets the transaction lock wait timeout.

The parameter value type is numeric.

14.7 soliddb_checkpoint_interval

This parameter sets the checkpoint write interval.

The parameter value type is numeric.

Chapter 15. Foreign Key Constraints

Table of Contents

15.1 Referential Actions

In relational databases, it is common for records in one relation to reference records in the same or other relations. The requirement that the referenced records must exist is called referential integrity. References can be made to link information together and it is an essential part of database normalization. One important type of referential integrity is the foreign key constraint.

A foreign key is a referential constraint between two tables in the database. The foreign key identifies a column or a set of columns in one (referencing) table that refers to a column or set of columns in another (referenced) table. The columns in the referenced table must form a primary key or unique key. The values in one row of the referencing columns must occur in a single row in the referenced table. Thus, a row in the referencing table cannot contain values that do not exist in the referenced table. Multiple rows in the referencing table may refer to the same row in the referenced table.

The referencing and referenced table may be the same table, that is, the foreign key refers back to the same table. Such a foreign key is known in SQL:2003 as a self-referencing or recursive foreign key. A table may have multiple foreign keys, and each foreign key may have a different referenced table. Each foreign key is independently forced by the database system. Therefore, cascading relationships between tables can be documented by using foreign keys.

Foreign keys are defined in the ANSI SQL Standard, by using a FOREIGN KEY constraint. The syntax to add such a constraint to an existing table is defined in SQL:2003. Leaving out the column list in the REFERENCES clause means that the foreign key references the primary key of the referenced table.

solidDB for MySQL supports foreign key constraints. solidDB uses the MySQL parser for foreign key definitions. See FOREIGN KEY Constraints in the MySQL 5.1 Reference Manual for more information on foreign keys and Using Foreign Keys in the MySQL 5.1 Reference Manual for more information on how to use foreign keys. Foreign key syntax can be found in CREATE TABLE Syntax and in ALTER TABLE Syntax.

[Note]Note

This version of solidDB for MySQL does not support the MATCH option.

solidDB for MySQL requires that both the referencing table and referenced tables are solidDB tables. Additionally, solidDB requires indexes on foreign keys and referenced keys so that foreign key checks can be fast and not require a table scan. The index on the foreign key is automatically created. Corresponding columns in the foreign key and the referenced key must have similar internal data types inside solidDB so that they can be compared without a type conversion. The size and sign of integer types must be the same. The length of string types need not be the same. If you specify a SET NULL action, make sure that you have not declared the columns in the child table as NOT NULL.

The default referential action is ON UPDATE RESTRICT and ON DELETE RESTRICT unless the ON UPDATE and ON DELETE attributes are separately given. Here is an example of creating tables using foreign keys:

CREATE TABLE t1 (id INT NOT NULL, PRIMARY KEY (id)) ENGINE=SOLIDDB;

CREATE TABLE t2 (id INT PRIMARY KEY, t1_id INT NOT NULL, 
FOREIGN KEY fkey(t1_id) REFERENCES t1(id) ON DELETE CASCADE)
ENGINE=SOLIDDB;

If you attempt to insert a row to table t2 with a value that does not exist in the parent table t1, you get an error message:

mysql> insert into t2 values (0, 0);
ERROR 1452 (23000): Cannot add or update a child row: a foreign key
constraint fails (CONSTRAINT 'fkey' FOREIGN KEY ('t1_id') REFERENCES 
't1' ('id') ON DELETE CASCADE ON UPDATE RESTRICT)

You must define tables in such an order that all referenced tables are created before the tables referencing them. If MySQL reports an error number 1005 from a CREATE TABLE statement, and the error message refers to error number 155, then the table creation has failed because a foreign key constraint was not correctly formed. Similarly, if an ALTER TABLE fails and it refers to error number 155, then the table alteration has failed because a foreign key constraint was incorrectly formed for the altered table.

mysql> CREATE TABLE t3 (id INT PRIMARY KEY, t1_id INT, INDEX par_ind
(t1_id), FOREIGN KEY (t1_id) REFERENCES t4(id) ON DELETE CASCADE)
ENGINE=SOLIDDB;

ERROR 1005 (HY000): Can't create table './test/t3.frm' (errno: 155)

You can also see an error message in the server log:

SOLID Table Error 13011: Table t4 does not exist

See below for a more complex example, in which a product_order table has foreign keys for two other tables. One foreign key references a two-column index in the product table. The other references a single-column index in the customer table:

create table customer(customer_id int not null, customer_name
varchar(80), primary key(customer_id)) engine=soliddb;

create table product(product_id int not null, product_price int,
primary key(product_id)) engine=soliddb;

create table product_order(order_id int not null, customer_id int not
null, product_id int not null, number_of_products int,  primary
key(order_id), foreign key (customer_id) references
customer(customer_id), foreign key (product_id) references
product(product_id)) engine=soliddb;

Additionally, the foreign key can reference the same table:

create table t1(a int not null, b int not null, d int, primary key(a),
foreign key (b) references t1(a) on update no action on delete no
action) engine=soliddb;

15.1 Referential Actions

A DBMS must ensure the data integrity of the database when rows in a referencing table are deleted or updated. SQL:2003 specifies five different referential actions that will take place in such a case:

  • CASCADE

  • RESTRICT

  • NO ACTION

  • SET NULL

  • SET DEFAULT

Each of the five referential actions will be discussed below.

Action

Description

CASCADE

All dependent rows are deleted if the referenced row is deleted. Likewise, the values in the foreign key columns are updated with the respective values in the referenced row.

RESTRICT

A row in the referenced table cannot be updated or deleted if dependent rows still exist. In that case, no data change is even attempted.

NO ACTION

The UPDATE or DELETE SQL statement is executed on the referenced table. The DBMS verifies at the end of the statement execution that none of the referential relationships is violated. The major difference to RESTRICT is that triggers or the statement semantics itself may give a result in which no foreign key relationship is violated. In that case, the statement can be executed successfully.

SET NULL

The foreign key values in the referencing row are set to NULL when the referenced row is updated or deleted. This is only possible if the respective columns in the referencing table are nullable. Due to the semantics of NULL, a referencing row with NULLs in the foreign key columns does not require a referenced row.

SET DEFAULT

Similarly to SET NULL, the foreign key values in the referencing row are set to the column default when the referenced row is updated or deleted. This version of solidDB for MySQL does not support referential action SET DEFAULT; instead an error message is issued:

create table t6(a int not null,
b int not null,
primary key(a),
foreign key ger (b) references t1(a)
on update set default on delete
set default) engine=soliddb;

ERROR 1005 (HY000): Can't create
table './test/t6.frm' (errno: 142)
                  

You can also see an error message in the server log:

070313  9:30:13 [ERROR] This version
of MySQL/solidDB does not support
SET_DEFAULT option on referential actions.
              

Chapter 16. Transaction Durability

Normally, when a transaction is committed, the database server writes data to two locations: the database file, and the transaction log file. However, the data are not necessarily written to those two locations at the same time. When a transaction is committed, the server writes the data to the transaction log file immediately, that is, as soon as the server commits the transaction. However, the server does not necessarily write the data to the database file immediately. The server may wait until it is less busy, or until it has accumulated multiple changes, before writing the data to the database file.

If the server shuts down abnormally (due to a power failure, for example) before all data have been written to the database file, the server can recover 100% of committed data by reading the combination of the database file and the transaction log file. Any changes since the last write to the database file are in the transaction log file. The server can read those changes from the log file and then use that information to update the database file. The process of reading changes from the log file and updating the database file is called “recovery”. At the end of the recovery process, the database file is 100% up to date.

The recovery process is automatically executed any time that the server restarts after an abnormal shutdown. The process is generally invisible to the user (except that there may be a delay before the server is ready to respond to new requests). Not surprisingly, to have a 100% recovery, you must have 100% of the transactions written to the log file. Normally, the database server writes data to the log file at the same time that the server commits the data. Thus committed transactions are stored on disk and will not be lost if the computer is shut down abnormally. This is called “strict durability”. The data that have been committed are “durable”, even if the server is shut down abnormally.

If durability is “strict”, data are written to the disk drive at the time that the data are committed. The user is not told that his data have been committed until the data were successfully written to the transaction log on disk. This ensures that the data are recoverable if the server shuts down abnormally, for example, due to a power failure. Strict durability makes it almost impossible to lose data unless the hard disk drive itself fails. If durability is “relaxed”, the user may be told that the data have been committed even before the data have been written to the transaction log on disk. The server may choose to delay writing the data by, for example, waiting until there are several transactions to write. If durability is relaxed, the server may lose a few committed transactions if there is a power failure before the data are written to disk.

Historically, the goal of most database servers has been to maximize safety, that is, to make sure that data are not lost due to a power failure or other problems. These database servers use “strict durability”. This approach is appropriate for many types of data, such as accounting data, where it is often unacceptable to lose track of even a single transaction. Some database servers have been designed to maximize performance, without regard to safety. This is acceptable in situations where, for example, you only need to sample data, or where the server can simply operate on the most recent set of data, regardless of the size of that set.

Suppose, for example, that you have a server containing statistical data about performance, for instance which computers experience the heaviest loads at particular times of the day. You might use such information to balance the load on your computers. This information changes over time, and “old” data are less valuable than “new” data. In fact, you might completely discard any data that are more than a week old. If you were to lose the performance and load balancing data, then your system would still function, and within a week you would have acquired a complete set of new data (assuming that you normally discard data older than one week). In this situation, occasional or small data loss is acceptable, and performance may be more important. solidDB allows you to specify whether you want logging to be “strict” (that is, to guarantee that all committed data can be recovered after an unexpected shutdown) or “relaxed” (that is, to allow some recent transactions to be lost in some circumstances).

You can increase performance by instructing the server that it does not necessarily have to write to the log file at the same time that it commits data. This allows the server to write to the log file later, perhaps when the server is less busy, or when several transactions can be written at once. This is called “relaxed durability”. It increases performance by decreasing the I/O load. If you set the transaction durability level to “relaxed”, you risk losing some data if the server shuts down abnormally after it has committed some data but before it has written those data to the transaction log. Therefore, you should use relaxed durability only when you can afford to lose a small amount of recent data.

If you can afford to lose a small amount of recent data, and if performance is crucial to you, then you may want to use relaxed durability. Relaxed durability is appropriate when each individual transaction is not crucial. For example, if you are monitoring system performance and you want to store data on response times, you may only be interested in average response times, which will not be significantly affected if you are missing a few pieces of data.

In fact, since measuring performance will itself affect performance (by using up resources such as Central Processing Unit (CPU) time and I/O bandwidth), you probably want your performance tracking operations themselves to have high performance (low cost) rather than high precision. Relaxed durability is appropriate in this situation. On the other hand, if you are tracking financial data, such as bill payments, then you probably want to ensure that 100% of your committed data are stored and recoverable. In this situation, you will want strict durability. You should use relaxed durability only when you can afford to lose a few of the most recent transactions. Otherwise, use strict durability. If you are not sure whether strict or relaxed durability is appropriate use strict durability.

Chapter 17. How AUTO_INCREMENT Columns Work in solidDB

If you specify an AUTO_INCREMENT column for a solidDB table, the table handle in the solidDB data dictionary contains a special sequence object called the “auto-increment sequence object” that is used in assigning new values for the column. This auto-increment sequence object is stored to disk.

If a user does not explicitly specify a value for an AUTO_INCREMENT column, solidDB increments the counter by one and assigns the new value to the column. If the user inserts a row that explicitly specifies the column value, and the value is bigger than the current counter value, the counter is set to the specified column value.

You may see gaps in the sequence of values assigned to the AUTO_INCREMENT column if you roll back transactions that have generated numbers using the counter.

If a user specifies NULL or 0 for the AUTO_INCREMENT column in an INSERT, solidDB treats the row as if the value had not been specified and generates a new value for it.

The behavior of the auto-increment mechanism is not defined if a user assigns a negative value to the column or if the value becomes bigger than the maximum integer that can be stored in the specified integer type.

solidDB supports the AUTO_INCREMENT = N table option in CREATE TABLE and ALTER TABLE statements, to set the initial counter value or alter the current counter value.

Chapter 18. solidDB and TRANSACTION ISOLATION LEVEL

In terms of the SQL:1992 transaction isolation levels, the solidDB default is REPEATABLE READ. solidDB offers all four transaction isolation levels described by the SQL standard. You can set the default isolation level for all sessions by using the --transaction-isolation option on the command line or in an option file. For example, you can set the option in the [mysqld] section of an option file like this:

[mysqld]
transaction-isolation = {READ-UNCOMMITTED | READ-COMMITTED
                        | REPEATABLE-READ | SERIALIZABLE}

A user can change the isolation level for a single session or for all new incoming connections with the SET TRANSACTION statement. Its syntax is as follows:

SET [SESSION | GLOBAL] TRANSACTION ISOLATION LEVEL
                       {READ UNCOMMITTED | READ COMMITTED
                       | REPEATABLE READ | SERIALIZABLE}
[Note]Note

There are hyphens in the level names for the --transaction-isolation option, but not for the SET TRANSACTION statement.

The default behavior is to set the isolation level for the next (not started) transaction. If you use the GLOBAL keyword, the statement sets the default transaction level globally for all new sessions created from that point on (but not for existing sessions). You need the SUPER privilege to do this. Using the SESSION keyword sets the default transaction level for all future transactions performed on the current session.

Any client is free to change the session isolation level (even in the middle of a transaction), or the isolation level for the next transaction.

You can determine the global and session transaction isolation levels by checking the value of the tx_isolation system variable with these statements:

SELECT @@global.tx_isolation;

SELECT @@tx_isolation;

Chapter 19. solidDB Performance Tuning Tips

There are different areas in solidDB that can result in performance degradation. In order to remedy performance problems, you need to determine the underlying cause. A bit later on you can find a table that lists common symptoms of poor performance, possible causes, and directs you to the solution.

SymptomsDiagnosisSolution

Slow response time for a single query.

Other concurrent access to the database is affected.

Disk may be busy.

Inefficient usage of indexes in the query.

Non-optimal decision from the Optimizer.

External sorting is being used.

If index definitions are missing, create new indexes or modify existing ones to match the indexing requirements of the slow query.

Run the EXPLAIN PLAN FOR statement for the slow query and verify whether the query optimizer is using the indexes.

Slow response time is experienced for all queries.

An increase in the number of concurrent users deteriorates the performance more than linearly.

When all users are thrown out and then reconnected, performance still does not improve.

Insufficient cache size.

Increase the cache size. Allocate for cache at least 0.5MB per concurrent user or 2-5% of the database size.

Slow performance during batch write operation as the database size increases.

There is an excessive amount of disk I/O.

The data are committed to the database in batches that are too small.

Data are written to disk in an order that is not supported by the primary key of the table.

Make sure that the auto-commit is switched off and the write operations are committed in batches of at least 100 rows per transaction.

Modify the primary keys or batch write processes so that write operations occur in the primary key order.

The server process footprint grows excessively and causes the the operating system to swap.

The disk is very busy.

SQL statements have not been closed and dropped after use.

Make sure that the statements that are no longer in use by the client application are committed or rolled back, closed, and dropped in a timely manner.

Chapter 20. solidDB Performance Monitoring

This chapter explains how to produce performance statistics output.

A pmon process is started by giving the command below:

mysql> SET GLOBAL soliddb_admin_command='pmon diff start soliddbpmon.out 1000';

Where soliddbpmon.out is the filename where the output is created and 1000 is the interval in milliseconds.

You can also append an existing file with command:

mysql> SET GLOBAL soliddb_admin_command='pmon diff start soliddbpmon.out 1000 append';

A pmon is stopped by giving the command below:

mysql> SET GLOBAL soliddb_admin_command='pmon diff stop';

You can import the pmon output file fx. to MS Excel (or other suitable tool) for further analysis or to send it to technical support.

For more information, please refer to solidDB Administrator Guide section Detailed DBMS Monitoring and Troubleshooting.

Chapter 21. Concurrency Control

solidDB offers two different types of concurrency control mechanisms, which are known as "pessimistic" and "optimistic". We explain both methods in the following chapters. By default, solidDB uses "pessimistic" concurrency control.

21.1 Pessimistic Concurrency Control

Pessimistic concurrency control is also known as "locking". Locks allow multiple users to safely share a database as long as all users are updating different data at the same time. For example, you can update Ms. Smith's record while I update Mr. Kumar's record.

When locks are used, the locks are placed as soon as any piece of the row is updated. Thus it is impossible for two users to update a row at the same time. As soon as one user gets a lock, no one else can process that row. This is a safe, conceptually simple approach. The disadvantage is that it requires overhead for every operation, whether or not two or more users are actually trying to access the same record. This overhead is small, but adds up because every row that is updated requires a lock. Furthermore, every time that a user tries to access a row, the system must also check whether the requested row(s) are already locked by another user (or connection).

Pessimistic concurrency control is called "pessimistic" because the system assumes the worst — it assumes that two users will want to update the same record at the same time, and then prevents that possibility by locking the record, no matter how unlikely conflicts actually are.

Here is an example of pessimistic concurrency control operation:

On T1, enter the statements below:

create table t2(a int not null) engine=soliddb
comment='MODE=PESSIMISTIC';
insert into t2 values (1),(2);
commit;
set autocommit = 0;
update t2 set a = 5 where a = 1;
    

On T2, enter the statements below:

set autocommit = 0;
update t2 set a = 7 where a = 1;
/* This query waits for T1 to release locks on table t2 */
    

On T2, you can see:

ERROR 1213 (40001): Deadlock found when trying to
get lock; try restarting transaction
    

On T1, enter the statements below:

commit;
    

T2 can now continue execution.

21.2 Optimistic Concurrency Control

An alternative approach to locking is called "optimistic" concurrency control. Optimistic concurrency control assumes that although conflicts are possible, they will be very rare. Instead of locking every record every time that it is used, the software merely looks for indications that two users actually did try to update the same record at the same time. If that evidence is found, then one user's updates are discarded (and of course the user is informed).

When using optimistic concurrency control, each time that the server reads a record to try to update it, the server makes a copy of the "version number" of the record and stores that copy for later reference. When it's time to write the updated data back to the disk drive, the server compares the original version number that it read with the version number that the disk drive now contains. If the version numbers are the same, then no one else changed the record and we can write our updated value. However, if the value we originally read and the current value on the disk are not the same, then someone has changed the data since we read it, and whatever operation we did is probably out-of-date, so we discard our version of the data and give the user an error message. Naturally, each time that we update a record, we also update the version number.

[Note]Note

If you want created tables to be optimistic by default, use the --soliddb_pessimistic = 0 configuration option.

Here is an example of optimistic concurrency control operation:

On T1, enter the statements below:

create table t2(a int not null) engine=soliddb
comment='MODE=OPTIMISTIC';
insert into t2 values (1),(2);
commit;
set autocommit = 0;
update t2 set a = 5 where a = 1;
    

on T2, enter the statements below:

set autocommit = 0;
update t2 set a = 7 where a = 1;
    

On T2, you can see:

ERROR 1213 (40001): Deadlock found when trying to
get lock; try restarting transaction
    

21.3 Differences Between Optimistic and Pessimistic Concurrency Control

When you use optimistic concurrency control, you don't find out there's a conflict until just before you write the updated data. In pessimistic locking, you find out there's a conflict as soon as you try to read the data. To use our analogy with banks again, pessimistic locking is like having a guard at the bank door who checks your account number when you try to enter; if someone else (a spouse, or a merchant to whom you wrote a check) is already in the bank accessing your account, then you can't enter until that other person finishes her transaction and leaves. Optimistic concurrency control, on the other hand, allows you to walk into the bank at any time and try to do your business, but at the risk that as you are walking out the door the bank guard will tell you that your transaction conflicted with someone else's and you'll have to go back and do the transaction again.

Optimistic and pessimistic concurrency controls differ in another important way besides the time at which conflicts are detected and error messages are issued. Pessimistic locking allows one user to not only block another user from updating the same record, but even from reading that record. If you use pessimistic locking and you get an exclusive lock, then no other user can even read that record. With optimistic locking, however, we don't check for conflicts except at the time that we write updated data to disk. If user1 updates a record and user2 only wants to read it, then user2 simply reads whatever data is on the disk and then proceeds, without checking whether the data is locked. User2 might see slightly out-of-date information if user1 has read the data and updated it but has not yet "committed" the transaction.

solidDB actually implements optimistic concurrency control in a more sophisticated way than this. Rather than giving each user "whatever version of data is on the disk at the moment it is read", solidDB can store multiple versions of each data row temporarily. Each user's transaction sees the database as it was at the time that the transaction started. This way, the data that each user sees is consistent throughout the transaction, and users are able to concurrently access the database. Data is always available to users because locking is not used; access is improved since deadlocks no longer apply. (Again, however, users run the risk that their changes will be thrown out if those changes conflict with another user's changes.) For details about how multiversioning is done, read Chapter 22, Implementation of Multiversioning.

Thus, for example, user1 might put an exclusive lock on a record and update it. When the record is updated, its version number changes. User2, who is using a read-only transaction, can read the previous version of the record even though the record has an exclusive lock on it.

Pessimistic locking allows you an option that optimistic locking does not offer. We said earlier that pessimistic locks fail "immediately" — that is, if you try to get an exclusive lock on a record and another user already has a lock (shared or exclusive) on that record, then you will be told that you can't get a lock. In fact, solidDB allows you the option of either failing immediately or of waiting a specified number of seconds before failing. You might specify a wait of 30 seconds; this means that if you initially try to get the lock and cannot, the server will continue trying to get the lock until either it gets the lock or until the 30 seconds has elapsed. In many cases, especially when transactions tend to be very short, you may find that setting a brief wait allows you to continue activities that otherwise would have been blocked by locks.

This wait mechanism applies only to pessimistic locking, not to optimistic concurrency control. There is no such thing as "waiting for an optimistic lock". If someone else changed the data since the time that you read it, no amount of waiting will prevent a conflict that has already occurred. In fact, since optimistic concurrency methods do not place locks, there is literally no "optimistic lock" to wait on.

Neither pessimistic nor optimistic concurrency control is "right" or "wrong". When properly implemented, both approaches ensure that your data is properly updated. In most scenarios, optimistic concurrency control is more efficient and offers higher performance, but in some scenarios pessimistic locking is more appropriate. In situations where there are a lot of updates and relatively high chances of users trying to update data at the same time, you probably want to use pessimistic locking. If the odds of conflict are very low (many records and relatively few users, or very few updates and mostly "read" operations), then optimistic concurrency control is usually the best choice. The decision will also be affected by how many records each user updates at a time.

Chapter 22. Implementation of Multiversioning

Multiversioning in solidDB is implemented with a feature called Bonsai Tree. Bonsai Tree is a small active “index” (data storage tree) that efficiently stores new data (deletes, inserts, updates) in central memory, while maintaining multiversion information. Multiple versions of a row (old and new) can co-exist in Bonsai Tree. Both the old and new data are used for concurrency control and for ensuring consistent read levels for all transactions without any locking overhead. With Bonsai Tree, the effort needed for concurrency control is significantly reduced.

When a transaction is started, it is given a sequential Transaction Start Number (TSN). The TSN is used as the “read level” of the transaction; all key values inserted later into the database from other sessions are not visible to searches within the current transaction. This offers consistent index read levels that appear as if the read operation was performed atomically at the time the transaction was started. This guarantees that read operations are presented with a consistent view of the data without the need for locks, which have higher overhead.

Old versions of rows (and the newer version(s) of those same rows) are kept in Bonsai Tree for as long as there are transactions that need to see those old versions. After the completion of all transactions that reference the old versions, the “old” versions of the data are discarded from Bonsai tree, and new committed data are moved from Bonsai Tree to the main storage tree. The presorted key values are merged as a background operation concurrently with normal database operations. This offers significant I/O optimization and load balancing. During the merge, the deleted key values are physically removed.

Chapter 23. solidDB Table and Index Structures

In solidDB, the main data structure used to store data, including tables and indexes, is a B-tree variation. The server uses two of these structures;

  • The main storage tree holds permanent data.

  • Bonsai Tree stores new data temporarily until they are ready to be moved to the main storage tree.

23.1 Main Storage Tree

The main storage tree contains all the data in the server, including tables and indexes. Internally, the server stores all data in “indexes” — there are no separate tables. Each index contains either complete primary keys (that is, all the data in a row) or secondary keys (what SQL refers to as “indexes” — just the column values that are part of the SQL index). There is no separate storage method for data rows, except for Binary Large Objects (BLOB) and other long column values.

All the indexes are stored in a single tree, which is the main storage tree. Within that tree, indexes are separated from each other by a system-defined index identification inserted in front of every key value. This mechanism divides the index tree into several logical index subtrees, where the key values of one index are clustered close to each other.

23.2 Bonsai Tree

Bonsai Tree is a small active “index” (data storage tree) that efficiently stores new data (deletes, inserts, updates) in central memory, while maintaining multiversion information. Multiple versions of a row (old and new) can co-exist in Bonsai Tree. Both the old and new data are used for concurrency control and for ensuring consistent read levels for all transactions without any locking overhead. With Bonsai Tree, the effort needed for concurrency control is significantly reduced.

When a transaction is started, it is given a sequential Transaction Start Number (TSN). The TSN is used as the “read level” of the transaction; all key values inserted later into the database from other sessions are not visible to searches within the current transaction. This offers consistent index read levels that appear as if the read operation was performed atomically at the time the transaction was started. This guarantees read operations are presented with a consistent view of the data without the need for locks, which have higher overhead.

Old versions of rows (and the newer version(s) of those same rows) are kept in the Bonsai Tree for as long as there are transactions that need to see those old versions. After the completion of all transactions that reference the old versions, the “old” versions of the data are discarded from the Bonsai tree, and new committed data are moved from Bonsai Tree to the main storage tree. The presorted key values are merged as a background operation concurrently with normal database operations. This offers significant I/O optimization and load balancing. During the merge, the deleted key values are physically removed.

Chapter 24. solidDB Status

solidDB collects performance statistics from the server. The statistics contain information about the solidDB internal state. You can use the SHOW ENGINE SOLIDDB STATUS SQL statement at any time to fetch the output of the performance statistics to your SQL client. See below for a command example:

mysql> SHOW ENGINE SOLIDDB STATUS\G

The performance statistics output includes the following information:

  • Memory size show the amount of memory solidDB has allocated from the operating system.

  • Transaction count statistics show the number of different transaction operations since startup.

  • Cache count statistics show cache hit rate and number of cache operations since startup. Cache hit rate usually should be above 95 percent. If it is below 95 percent, consider increasing the cache size.

  • Database statistics show a number of the most important database operations since startup. "Index writes after last merge" is an important figure here. It reveals the size of the multi-versioning storage tree of solidDB, known as the Bonsai Tree. The smaller this value is, the better the server performance. A large value indicates that there is a long-running transaction active in the engine. Note that an excessively large Bonsai Tree causes performance degradation.

Example of the statistics output:

mysql> show engine soliddb status;
+-------------------------------------------------------------------+
| Status                                                            |
|                                                                   |
+-------------------------------------------------------------------+
| Memory size:
    534535 kilobytes
Transaction count statistics:
    Commit Abort Rollback    Total Read-only  Trxbuf  Active Validate
        40     0        8       48        47       0       1        0
Cache count statistics:
    Hit rate      Find      Read     Write
    94.4          1171      66        0        
Database statistics:
    Index writes            3  After last merge      0
    Log writes              0  After last cp         0
    Active searches         0  Average               2
    Database size    3392064 kilobytes
    Log size         1531904 kilobytes
|
+-------------------------------------------------------------------+
1 row in set (0.00 sec)

Chapter 25. Show Status

solidDB for MySQL maintains many status variables that provide information about its operation and performance. You can view these variables and their values by using the SHOW [GLOBAL] STATUS statement. For more information about MySQL server status variables see Status Variables. See also Chapter 24, solidDB Status.

See below for an example on how to retrieve status variables in solidDB for MySQL:

mysql> SHOW STATUS LIKE 'solidDB%';
+----------------------------------------+---------------------+
| Variable_name                          | Value               |
+----------------------------------------+---------------------+
| solidDB_memory_size                    | 606386              | 
| solidDB_transaction_commits            | 77                  | 
| solidDB_transaction_rollbacks          | 0                   | 
| solidDB_transaction_aborts             | 8                   | 
| solidDB_transaction_total              | 85                  | 
| solidDB_transaction_readonly           | 84                  | 
| solidDB_transaction_trxbuf             | 0                   | 
| solidDB_transaction_activecnt          | 1                   | 
| solidDB_transaction_validatecnt        | 0                   | 
| solidDB_cache_hit_rate                 | 99                  | 
| solidDB_cache_finds                    | 3821                | 
| solidDB_cache_reads                    | 25                  | 
| solidDB_cache_writes                   | 0                   | 
| solidDB_indexmerge_active              | OFF                 | 
| solidDB_index_writes                   | 3                   | 
| solidDB_index_writes_after_merge       | 0                   | 
| solidDB_log_writes                     | 0                   | 
| solidDB_log_writes_after_cp            | 0                   | 
| solidDB_active_searches                | 0                   | 
| solidDB_average_searches               | 2                   | 
| solidDB_database_size                  | 16064               | 
| solidDB_log_size                       | 5184                | 
| solidDB_checkpoint_active              | OFF                 | 
| solidDB_backup_active                  | OFF                 | 
| solidDB_version                        | 5.0.45-solidDB-0079 | 
| solidDB_pmon_fileopen                  | 4                   | 
| solidDB_pmon_fileread                  | 34                  | 
| solidDB_pmon_filewrite                 | 2                   | 
| solidDB_pmon_fileappend                | 0                   | 
| solidDB_pmon_fileflush                 | 2                   | 
| solidDB_pmon_filelock                  | 2                   | 
| solidDB_pmon_cachefind                 | 3821                | 
| solidDB_pmon_cachefileread             | 25                  | 
| solidDB_pmon_cachefilewrite            | 0                   | 
| solidDB_pmon_cacheprefetch             | 0                   | 
| solidDB_pmon_cacheprefetchwait         | 0                   | 
| solidDB_pmon_cachepreflush             | 0                   | 
| solidDB_pmon_cachelruwrite             | 0                   | 
| solidDB_pmon_cacheslotwait             | 0                   | 
| solidDB_pmon_sqlprepare                | 0                   | 
| solidDB_pmon_sqlexecute                | 0                   | 
| solidDB_pmon_sqlfetch                  | 0                   | 
| solidDB_pmon_dbeinsert                 | 3                   | 
| solidDB_pmon_dbedelete                 | 0                   | 
| solidDB_pmon_dbeupdate                 | 0                   | 
| solidDB_pmon_dbefetch                  | 2087                | 
| solidDB_pmon_dbefetchuniquefound       | 0                   | 
| solidDB_pmon_dbefetchuniquenotfound    | 0                   | 
| solidDB_pmon_transcommit               | 77                  | 
| solidDB_pmon_transabort                | 0                   | 
| solidDB_pmon_transrdonly               | 84                  | 
| solidDB_pmon_transbufcnt               | 0                   | 
| solidDB_pmon_transbufclean             | 5                   | 
| solidDB_pmon_transbufadded             | 4                   | 
| solidDB_pmon_transbufremoved           | 4                   | 
| solidDB_pmon_transvldcnt               | 0                   | 
| solidDB_pmon_transactcnt               | 1                   | 
| solidDB_pmon_transreadlevel            | 2887                | 
| solidDB_pmon_indwrite                  | 3                   | 
| solidDB_pmon_indwritesaftermerge       | 0                   | 
| solidDB_pmon_logwrites                 | 0                   | 
| solidDB_pmon_logfilewrite              | 0                   | 
| solidDB_pmon_logwritesaftercp          | 0                   | 
| solidDB_pmon_logsize                   | 5184                | 
| solidDB_pmon_srchnactive               | 0                   | 
| solidDB_pmon_dbsize                    | 16064               | 
| solidDB_pmon_dbfreesize                | 14656               | 
| solidDB_pmon_memsize                   | 606386              | 
| solidDB_pmon_mergequickstep            | 0                   | 
| solidDB_pmon_mergestep                 | 30                  | 
| solidDB_pmon_mergepurgestep            | 0                   | 
| solidDB_pmon_mergeuserstep             | 0                   | 
| solidDB_pmon_mergeoper                 | 23                  | 
| solidDB_pmon_mergecleanup              | 0                   | 
| solidDB_pmon_mergeact                  | 0                   | 
| solidDB_pmon_mergewrites               | 0                   | 
| solidDB_pmon_mergefilewrite            | 0                   | 
| solidDB_pmon_mergefileread             | 0                   | 
| solidDB_pmon_mergelevel                | 2887                | 
| solidDB_pmon_backupstep                | 0                   | 
| solidDB_pmon_backupact                 | 0                   | 
| solidDB_pmon_checkpointact             | 0                   | 
| solidDB_pmon_checkpointcount           | 0                   | 
| solidDB_pmon_checkpointfilewrite       | 0                   | 
| solidDB_pmon_checkpointfileread        | 4                   | 
| solidDB_pmon_estsamplesread            | 5                   | 
| solidDB_pmon_logflushes_logical        | 0                   | 
| solidDB_pmon_logflushes_physical       | 0                   | 
| solidDB_pmon_loggroupcommit_wakeups    | 1                   | 
| solidDB_pmon_logflushes_fullpages      | 0                   | 
| solidDB_pmon_logwaitflush              | 0                   | 
| solidDB_pmon_logmaxwritequeuerecords   | 0                   | 
| solidDB_pmon_logmaxwritequeuebytes     | 0                   | 
| solidDB_pmon_ss_threadcount            | 13                  | 
| solidDB_pmon_waitreadlevel_count       | 0                   | 
| solidDB_pmon_dbe_lock_ok               | 57                  | 
| solidDB_pmon_dbe_lock_timeout          | 0                   | 
| solidDB_pmon_dbe_lock_deadlock         | 0                   | 
| solidDB_pmon_dbe_lock_wait             | 0                   | 
| solidDB_pmon_mysql_rnd_init            | 0                   | 
| solidDB_pmon_mysql_index_read          | 0                   | 
| solidDB_pmon_mysql_fetch_next          | 0                   | 
| solidDB_pmon_mysql_cursor_create       | 0                   | 
| solidDB_pmon_mysql_cursor_reset_full   | 0                   | 
| solidDB_pmon_mysql_cursor_reset_simple | 0                   | 
| solidDB_pmon_mysql_cursor_reset_fetch  | 0                   | 
| solidDB_pmon_mysql_cursor_cache_find   | 0                   | 
| solidDB_pmon_mysql_cursor_cache_hit    | 0                   | 
| solidDB_pmon_mysql_connect             | 1                   | 
| solidDB_pmon_mysql_commit              | 0                   | 
| solidDB_pmon_mysql_rollback            | 0                   | 
+----------------------------------------+---------------------+
111 rows in set (0.00 sec)


  
  • solidDB_memory_size

    This parameter value indicates the amount of memory solidDB has allocated from the operating system.

  • solidDB_transaction_commits

    This parameter value indicates the number of committed transactions.

  • solidDB_transaction_rollbacks

    This parameter value indicates the number of rollbacked transactions.

  • solidDB_transaction_aborts

    This parameter value indicates the number of aborted transactions.

  • solidDB_transaction_total

    This parameter value indicates the total number of transactions.

  • solidDB_transaction_readonly

    This parameter value indicates the number of read-only transactions.

  • solidDB_transaction_trxbuf

    This parameter value indicates the number of transactions in the transaction buffer.

  • solidDB_transaction_activecnt

    This parameter value indicates the number of active transactions.

  • solidDB_transaction_validatecnt

    This parameter value indicates the number of validated transactions.

  • solidDB_cache_hit_rate

    This parameter value indicates the cache hit rate in percentage.

  • solidDB_cache_finds

    This parameter value indicates the total number of requests for a storage engine to perform a cache find operation.

  • solidDB_cache_reads

    This parameter value indicates the total number of requests for a storage engine to perform a cache read operation.

  • solidDB_cache_writes

    This parameter value indicates the total number of requests for a storage engine to perform a cache write operation.

  • solidDB_indexmerge_active

    This parameter value indicates if solidDB is currently performing an index merge operation. The possible values are ON, which indicates that an index merge operation is being performed and OFF, which indicates that an index merge operation is not being performed.

  • solidDB_index_writes

    This parameter value indicates the total number of requests for a storage engine to perform an index write operation.

  • solidDB_index_writes_after_merge

    This parameter value indicates the number of requests for a storage engine to perform an index write operation after the previous merge operation.

  • solidDB_log_writes

    This parameter value indicates the total number of requests for a storage engine to perform a log write operation.

  • solidDB_log_writes_after_cp

    This parameter value indicates the number of requests for a storage engine to perform a log write operation after the previous checkpoint.

  • solidDB_active_searches

    This parameter value indicates the number of currently active search operations.

  • solidDB_average_searches

    This parameter value indicates the average number of requests for a storage engine to perform a search operation since startup. The value is given as a percentage of transactions.

  • solidDB_database_size

    This parameter value shows the database size in kilobytes.

  • solidDB_log_size

    This parameter value shows the log size in kilobytes.

  • solidDB_checkpoint_active

    This parameter value indicates if solidDB is currently performing a checkpointing operation. The possible values are ON, which indicates that a checkpointing operation is being performed and OFF, which indicates that a checkpointing operation is not being performed.

  • solidDB_backup_active

    This parameter value indicates if solidDB is currently performing a backup operation. The possible values are ON, which indicates that a backup operation is being performed and OFF, which indicates that a backup operation is not being performed.

  • solidDB_version

    This parameter value indicates the solidDB version.

  • solidDB_pmon_fileopen

    This parameter value indicates the number of file open calls per second.

  • solidDB_pmon_fileread

    This parameter value indicates the number of file read calls per second.

  • solidDB_pmon_filewrite

    This parameter value indicates the number of file write calls per second.

  • solidDB_pmon_fileappend

    This parameter value indicates the number of file append calls per second.

  • solidDB_pmon_fileflush

    This parameter value indicates the number of file flush calls per second.

  • solidDB_pmon_filelock

    This parameter value indicates the number of file lock calls per second.

  • solidDB_pmon_cachefind

    This parameter value indicates the number of cache fetches per second.

  • solidDB_pmon_cachefileread

    This parameter value indicates the number of cache misses per second.

  • solidDB_pmon_cachefilewrite

    This parameter value indicates the number of cache page flushes per second.

  • solidDB_pmon_cacheprefetch

    This parameter value indicates the number of cache prefetched pages per second.

  • solidDB_pmon_cacheprefetchwait

    This parameter value indicates the number of cache waits for prefetched pages per second.

  • solidDB_pmon_cachepreflush

    This parameter value indicates the number of preflushed cache pages per second.

  • solidDB_pmon_cachelruwrite

    This parameter value indicates how many pages of the cache have been written on disk.

  • solidDB_pmon_cacheslotwait

    This parameter value indicates how many times the system has waited for a cache slot.

  • solidDB_pmon_sqlprepare

    This parameter value indicates the number of SQL prepare statements per second.

  • solidDB_pmon_sqlexecute

    This parameter value indicates the number of SQL execute statements per second.

  • solidDB_pmon_sqlfetch

    This parameter value indicates the number of SQL fetch statements per second.

  • solidDB_pmon_dbeinsert

    This parameter value indicates the number of table engine row inserts per second.

  • solidDB_pmon_dbedelete

    This parameter value indicates the number of table engine row deletes per second.

  • solidDB_pmon_dbeupdate

    This parameter value indicates the number of table engine row updates per second.

  • solidDB_pmon_dbefetch

    This parameter value indicates the number of table engine row fetches per second.

  • solidDB_pmon_dbefetchuniquefound

    This parameter value indicates the number of unique fetches.

  • solidDB_pmon_dbefetchuniquenotfound

    This parameter value indicates how many times a normal fetch has been made.

  • solidDB_pmon_transcommit

    This parameter value indicates the number of committed transactions per second.

  • solidDB_pmon_transabort

    This parameter value indicates the number of aborted transactions per second.

  • solidDB_pmon_transrdonly

    This parameter value indicates the number of read-only transactions per second.

  • solidDB_pmon_transbufcnt

    This parameter value indicates the number of buffered transactions per second.

  • solidDB_pmon_transbufclean

    This parameter value indicates the cumulative number of transaction buffer cleanup operations since startup.

  • solidDB_pmon_transbufadded

    This parameter value indicates the cumulative number of transactions added to buffer since startup.

  • solidDB_pmon_transbufremoved

    This parameter value indicates the cumulative number of transactions removed from buffer since startup.

  • solidDB_pmon_transvldcnt

    This parameter value indicates the current number of active commit-time validations.

  • solidDB_pmon_transactcnt

    This parameter value indicates the current number of active transactions.

  • solidDB_pmon_transreadlevel

    This parameter value indicates the transaction read level.

  • solidDB_pmon_indwrite

    This parameter value indicates the number of index writes per second.

  • solidDB_pmon_indwritesaftermerge

    This parameter value indicates the cumulative number of index writes since the latest merge operation.

  • solidDB_pmon_logwrites

    This parameter value indicates the number of log record writes per second.

  • solidDB_pmon_logfilewrite

    This parameter value indicates the number of log block writes per second.

  • solidDB_pmon_logwritesaftercp

    This parameter value indicates the cumulative number of log record writes since the latest checkpoint operation.

  • solidDB_pmon_logsize

    This parameter value indicates the total size of the log file in kilobytes.

  • solidDB_pmon_srchnactive

    This parameter value indicates the number of active table engine-level searches.

  • solidDB_pmon_dbsize

    This parameter value indicates the total size of the database on the disk, in kilobytes.

  • solidDB_pmon_dbfreesize

    This parameter value indicates the free space in the database on page level, in kilobytes.

  • solidDB_pmon_memsize

    This parameter value indicates the total size on dynamically allocated memory in kilobytes.

  • solidDB_pmon_mergequickstep

    This parameter value indicates the number of quick merge steps per second.

  • solidDB_pmon_mergestep

    This parameter value indicates the number of merge steps per second.

  • solidDB_pmon_mergepurgestep

    This parameter value indicates the number of node split-inflicted merge keys per second (if enabled).

  • solidDB_pmon_mergeuserstep

    This parameter value indicates the number of user thread-activated merge rows per second.

  • solidDB_pmon_mergeoper

    This parameter value indicates the number of lower-level merge operations per second.

  • solidDB_pmon_mergecleanup

    This parameter value indicates the number of transaction buffer cleanup calls per second (if split purge enabled).

  • solidDB_pmon_mergeact

    This parameter value indicates if merge is active. The value is either yes or no (1/0).

  • solidDB_pmon_mergewrites

    This parameter value indicates the number of index entries waiting for merge.

  • solidDB_pmon_mergefilewrite

    This parameter value indicates the number of merge-inflicted file writes per second.

  • solidDB_pmon_mergefileread

    This parameter value indicates the number of merge-inflicted file reads per second.

  • solidDB_pmon_mergelevel

    This parameter value indicates the current merge level, that is, read level of the oldest active transaction.

  • solidDB_pmon_backupstep

    This parameter value indicates the database backup steps per second.

  • solidDB_pmon_backupact

    This parameter value indicates if backup is active. The value is either yes or no (1/0).

  • solidDB_pmon_checkpointact

    This parameter value indicates if checkpoint is active. The value is either yes or no (1/0).

  • solidDB_pmon_checkpointact

    This parameter value indicates the checkpoint serial number from startup.

  • solidDB_pmon_checkpointfilewrite

    This parameter value indicates the number of checkpoint file writes per second.

  • solidDB_pmon_checkpointfileread

    This parameter value indicates the number of checkpoint file reads per second.

  • solidDB_pmon_estsamplesread

    This parameter value indicates the number of estimator sample refresh calls per second.

  • solidDB_pmon_logflushes_logical

    This parameter value indicates the number of logical log flushes per second.

  • solidDB_pmon_logflushes_physical

    This parameter value indicates the number of physical log flushes per second.

  • solidDB_pmon_loggroupcommit_wakeups

    This parameter value indicates the number of group commit wakeups per second.

  • solidDB_pmon_logflushes_fullpages

    This parameter value indicates the number of log page full flushes per second.

  • solidDB_pmon_logwaitflush

    This parameter value indicates the current number of user threads waiting for log operation.

  • solidDB_pmon_logmaxwritequeuerecords

    This parameter value indicates the number of log writes while the log write queue is full (expressed in number of records).

  • solidDB_pmon_logmaxwritequeuebytes

    This parameter value indicates the number of log writes while the log write queue is full (expressed in bytes).

  • solidDB_pmon_ss_threadcount

    This parameter value indicates the current number of threads.

  • solidDB_pmon_waitreadlevel_count

    This parameter value indicates the number of waits per second for read level at commit.

  • solidDB_pmon_dbe_lock_ok

    This parameter value indicates the number of successful lock requests per second.

  • solidDB_pmon_dbe_lock_timeout

    This parameter value indicates the number of lock timeouts per second.

  • solidDB_pmon_dbe_lock_deadlock

    This parameter value indicates the number of deadlocks per second.

  • solidDB_pmon_dbe_lock_wait

    This parameter value indicates the number of waits per second.

  • solidDB_pmon_mysql_rnd_init

    This parameter value indicates how many times MySQL has called the rnd_init() function.

  • solidDB_pmon_mysql_index_read

    This parameter value indicates how many times MySQL has called the index_read() function.

  • solidDB_pmon_mysql_fetch_next

    This parameter value indicates how many times MySQL has called the fetch_next() function.

  • solidDB_pmon_mysql_cursor_create

    This parameter value indicates how many times MySQL has called the cursor_create() function.

  • solidDB_pmon_mysql_cursor_reset_full

    This parameter value indicates how many times MySQL has called the cursor_reset_full() function.

  • solidDB_pmon_mysql_cursor_reset_simple

    This parameter value indicates how many times MySQL has called the cursor_reset_simple() function.

  • solidDB_pmon_mysql_cursor_reset_fetch

    This parameter value indicates how many times MySQL has called the cursor_reset_fetch() function.

  • solidDB_pmon_mysql_cursor_cache_find

    This parameter value indicates how many times MySQL has called the cursor_cache_find() function.

  • solidDB_pmon_mysql_cursor_cache_hit

    This parameter value indicates how many times MySQL has called the cursor_cache_hit() function.

  • solidDB_pmon_mysql_connect

    This parameter value indicates how many times MySQL has called the connect() function.

  • solidDB_pmon_mysql_commit

    This parameter value indicates how many times MySQL has called the commit() function.

  • solidDB_pmon_mysql_rollback

    This parameter value indicates how many times MySQL has called the rollback() function.

Chapter 26. Obtaining solidDB for MySQL Version

You can display solidDB version information by using command:

show status like 'soliddb_version';

Here is an example output:

mysql> show status like 'soliddb_version';
+-----------------+---------------------+
| Variable_name   | Value               |
+-----------------+---------------------+
| solidDB_version | 5.0.45-solidDB-0079 | 
+-----------------+---------------------+
1 row in set (0.00 sec)
    

Chapter 27. Troubleshooting solidDB

The following guidelines apply to troubleshooting solidDB problems:

  • When an operation fails or you suspect an error, look at the MySQL server error log. The log file is in the data directory and has the .err suffix.

  • Examine also solidDB logs. The log files are solmsg.out and solerror.out.

  • When troubleshooting, it is usually best to run the MySQL server from the command prompt, rather than through the mysqld_safe wrapper. In this way, you can see what mysqld prints to the console, and have a better grasp of what is happening.

  • If you suspect that a table is corrupt, run CHECK TABLE on that table.

27.1 Cachesize Too Large

If you see the error message below, your database cache size is too large.

SOLID Fatal error:
Out of central memory when allocating buffer memory (size =xxxxxxxxx)
    

You can solve this problem as follows:

  1. Decrease the soliddb_cachesize parameter value.

  2. Delete the database files and log files.

27.2 Cachesize Too Small

If you see an error message such as the one below, your database cache size is too small.

SOLID Fatal error:
Too little cache memory has been specified for the SOLID process:

        [IndexFile]
        CacheSize=0    
        
Please edit the solid.ini file to increase this parameter value at least
to 172032 bytes and restart the SOLID process.        
    

You can solve this problem as follows:

  1. Increase the soliddb_cachesize parameter value as required in the error message.

  2. Delete the database files and log files.

Chapter 28. solidDB File Space Management and Disk I/O

In solidDB, data and indexes are stored in the same file(s). The term “index file” is used as a synonym for the term “database file”. The soliddb_filespec parameter specifies the name and location of the file(s) used to store the database. To define the location and maximum size for the file(s), the soliddb_filespec parameter accepts the following two arguments:

  • Database filename

  • Maximum file-size

Example:

soliddb_filespec=solid.db 2000M

The size unit is 1 byte. You can use K, M and G unit symbols to denote kilobytes, megabytes and gigabytes, respectively. The maximum file-size is 4GB*blocksize-1. With the default 8KB block size, this makes 32TB - 1.

The soliddb_filespec parameter is also used to divide the database into multiple files and onto multiple disks. To divide the database into multiple files, specify another database specification. The index file will be written to the second file if it grows over the maximum value of the first parameter.

In the following example, the parameters divide the database file on the disks C:, D:, and E: to be split after growing larger than about 1 GB. Notice that the slash at the end of the first line has been added for layout purposes.

soliddb_filespec=C:\soldb\solid1.db/
1G,D:\soldb\solid2.db 1G,E:\soldb\solid3.db 1G
[Note]Note

The index file locations entered must be valid path names in the server's operating system. For example, if the server runs on a Unix operating system, path separators must be slashes instead of backlashes.

Although the database files reside in different directories, the filenames must be unique. There is no practical limit to the number of database files you can use.

Splitting the database file on multiple disks will increase the performance of the server because multiple disk heads will provide parallel access to the data in your database.

You may need to have multiple files on a single disk if your physical disk is portioned into multiple logical disks and no single logical disk can accommodate the size of the database file you expect to create.

If the database file is split into multiple physical disks, the multi-threaded solidDB engine is capable of assigning a separate disk I/O thread for each device. This way the server can perform database file I/O in a parallel manner.

If your database has reached the maximum size specified by the soliddb_filespec parameter, you have two options.

  • You can shut down the server, add a new database file specification or increase the size field, and restart the server.

  • You can add a new database file dynamically using a MySQL client as follows:

    shell> mysql
    shell> SET GLOBAL soliddb_filespec='solid5.db 1G';
    shell> exit;
              

[Warning]Warning

Do not attempt to use the soliddb_filespec parameter to decrease the size of a database; you risk losing pre-existing data and corrupting the database.

[Important]Important

Remember to add new file specification to the MySQL config file after you have added dynamically a new database file. You do not need to restart the server after you have added this new database file.

Chapter 29. solidDB Error Handling

As a rule, solidDB uses the MySQL error messages. However, there are situations where solidDB writes error messages to the MySQL log. The possible error messages are:

ErrorDescription

solidDB: Error: You may not provide a path for both <value> "FileNameTemplate = <value> and <value> LogDir = <value>

An attempt has been made to provide the FileNameTemplate in the solid.ini configuration file. Remove the solid.ini configuration file. If you have a reason for keeping it, provide the FileNameTemplate parameter without the directory path in line with the following example:

FileNameTemplate = sol####.log

solidDB: Error: Parse error on filespec <value>

The system cannot parse the soliddb_filespec parameter. This parameter defines the location and maximum size of the index file. You must provide the soliddb_filespec parameter in line with the following example:

soliddb_filespec=c:\soldb\solid.db 200000000

solidDB: Error: Illegal or missing argument filesize <value>

The file-size is missing from the soliddb_filespec parameter. This parameter defines the location and maximum size of the index file. You must provide the soliddb_filespec parameter in line with the following example:

soliddb_filespec=c:\soldb\solid.db 200000000

solidDB: Error: illegal value for file size.

An illegal file-size has been detected in the soliddb_filespec parameter. The minimum file-size is 10 MB. The maximum file-size is 4GB*blocksize-1. For more information, see Chapter 7, solidDB for MySQL Configuration.

solidDB: Error: Adding a new database file failed

or

solidDB: Error: SOLID System Error 11000: File open failure

It was not possible to add a new database file. The database was dropped. Check that the given directory path exists and that your operating system supports the given file format name.

Chapter 30. MySQL Drivers

MySQL offers standard database driver connectivity for using MySQL with applications and tools that are compatible with industry standards ODBC and JDBC. The drivers can be downloaded from MySQL web pages, see http://dev.mysql.com/downloads/connector/.

Index

D

database
creating, Creating a Database
introduced, solidDB for MySQL Overview
shutting down, Shutting Down the Database
default filenames, Starting the Server
dynamic configuration variables
soliddb_admin_command, soliddb_admin_command
soliddb_backupdir, soliddb_backupdir
soliddb_checkpoint_interval, soliddb_checkpoint_interval
soliddb_checkpoint_time, soliddb_checkpoint_time
soliddb_durability_level, soliddb_durability_level
soliddb_filespec, soliddb_filespec
soliddb_lock_wait_timeout, soliddb_lock_wait_timeout

F

foreign key constraints, Foreign Key Constraints

M

MySQL query tool, Opening the MySQL Query Tool
mysqld
solidDB parameters, solidDB for MySQL Configuration
soliddb_filespec, solidDB for MySQL Configuration

P

performance
improving, solidDB Performance Tuning Tips
monitoring, solidDB Performance Monitoring
problems
troubleshooting solidDB, Troubleshooting solidDB

T

tables
creating, Creating and Using solidDB Tables
solidDB, solidDB Table and Index Structures
transactions
transaction durability, Transaction Durability
troubleshooting solidDB, Troubleshooting solidDB
CHECK TABLE, Troubleshooting solidDB
error log, Troubleshooting solidDB
solerror.out, Troubleshooting solidDB
solmsg.out, Troubleshooting solidDB

U

upgrading
from MySQL 5.0 to 5.1, Upgrading MySQL from 5.0 to 5.1
from MySQL 5.1 without solidDB to 5.1 with solidDB, Upgrading MySQL from 5.1 without solidDB to 5.1 with solidDB
- Solid Information Technology, Ltd -