<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Strict//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"> <!-- Copyright 2004-2007 H2 Group. Licensed under the H2 License, Version 1.0 (http://h2database.com/html/license.html). Initial Developer: H2 Group --> <html xmlns="http://www.w3.org/1999/xhtml" lang="en" xml:lang="en"> <head><meta http-equiv="Content-Type" content="text/html;charset=utf-8" /><title> Features </title><link rel="stylesheet" type="text/css" href="stylesheet.css" /> <script type="text/javascript" src="navigation.js"></script> </head><body onload="frameMe();"> <table class="content"><tr class="content"><td class="content"><div class="contentDiv"> <h1>Features</h1> <a href="#feature_list"> Feature List</a><br /> <a href="#comparison"> Comparison to Other Database Engines</a><br /> <a href="#products_work_with"> H2 in Use</a><br /> <a href="#connection_modes"> Connection Modes</a><br /> <a href="#database_url"> Database URL Overview</a><br /> <a href="#file_encryption"> Connecting to a Database with File Encryption</a><br /> <a href="#database_file_locking"> Database File Locking</a><br /> <a href="#database_only_if_exists"> Opening a Database Only if it Already Exists</a><br /> <a href="#closing_the_database"> Closing the Database</a><br /> <a href="#log_index_changes"> Log Index Changes</a><br /> <a href="#custom_access_mode"> Custom File Access Mode</a><br /> <a href="#multiple_connections"> Multiple Connections</a><br /> <a href="#database_file_layout"> Database File Layout</a><br /> <a href="#logging_recovery"> Logging and Recovery</a><br /> <a href="#compatibility_modes"> Compatibility Modes</a><br /> <a href="#trace_options"> Using the Trace Options</a><br /> <a href="#read_only"> Read Only Databases</a><br /> <a href="#storage_formats"> Binary and Text Storage Formats</a><br /> <a href="#low_disk_space"> Graceful Handling of Low Disk Space Situations</a><br /> <a href="#computed_columns"> Computed Columns / Function Based Index</a><br /> <a href="#multi_dimensional"> Multi-Dimensional Indexes</a><br /> <a href="#passwords"> Using Passwords</a><br /> <a href="#user_defined_functions"> User Defined Functions and Stored Procedures</a><br /> <a href="#triggers"> Triggers</a><br /> <a href="#compacting"> Compacting a Database</a><br /> <a href="#cache_settings"> Cache Settings</a><br /> <a href="#why_java"> Why Java</a><br /> <br /><a name="feature_list"></a> <h2>Feature List</h2> <h3>Main Features</h3> <ul> <li>Very fast database engine </li><li>Free, with source code </li><li>Written in Java </li><li>Supports standard SQL, JDBC API </li><li>Embedded and Server mode, Clustering support </li><li>Strong security features </li><li>Experimental native version (GCJ) and ODBC drivers </li></ul> <h3>Additional Features</h3> <ul> <li>Disk based or in-memory databases and tables, read-only database support, temporary tables </li><li>Transaction support (read committed and serializable transaction isolation), 2-phase-commit </li><li>Multiple connections, table level locking </li><li>Cost based optimizer, using a genetic algorithm for complex queries, zero-administration </li><li>Scrollable and updatable result set support, large result set, external result sorting, functions can return a result set </li><li>Encrypted database (AES or XTEA), SHA-256 password encryption, encryption functions, SSL </li></ul> <h3>SQL Support</h3> <ul> <li>Support for multiple schemas, information schema </li><li>Referential integrity / foreign key constraints with cascade, check constraints </li><li>Inner and outer joins, subqueries, read only views and inline views </li><li>Triggers and Java functions / stored procedures </li><li>Many built-in functions, including XML and lossless data compression </li><li>Wide range of data types including large objects (BLOB/CLOB) and arrays </li><li>Sequence and autoincrement columns, computed columns (can be used for function based indexes) </li><li>ORDER BY, GROUP BY, HAVING, UNION, LIMIT, TOP </li><li>Collation support, users, roles </li><li>Compatibility modes for HSQLDB, MySQL and PostgreSQL </li></ul> <h3>Security Features</h3> <ul> <li>Includes a solution for the SQL injection problem </li><li>User password authenticated uses SHA-256 and salt </li><li>User passwords are never transmitted in plain text over the network (even when using insecure connections) </li><li>All database files (including script files that can be used to backup data) can be encrypted using AES-256 and XTEA encryption algorithms </li><li>The remote JDBC driver supports TCP/IP connections over SSL/TLS </li><li>The built-in web server supports connections over SSL/TLS </li><li>Passwords can be sent to the database using char arrays instead of Strings </li></ul> <h3>Other Features and Tools</h3> <ul> <li>Small footprint (smaller than 1 MB), low memory requirements </li><li>Multiple index types (b-tree, tree, hash, linear hash) </li><li>Support for multi-dimensional indexes </li><li>CSV (comma separated values) file support </li><li>Support for linked tables, and a built-in virtual 'range' table </li><li>EXPLAIN PLAN support, sophisticated trace options </li><li>Database closing can be delayed or disabled to improve the performance </li><li>Web-based Console application (English, German, partially French and Spanish) with autocomplete </li><li>The database can generate SQL script files </li><li>Contains a recovery tool that can dump the contents of the data file </li><li>Automatic re-compilation of prepared statements </li><li>Uses a small number of database files, binary and text storage formats, graceful handling of low disk space situations </li><li>Uses a checksum for each record and log entry for data integrity </li><li>Well tested (high code coverage, randomized stress tests) </li></ul> <br /><a name="comparison"></a> <h2>Comparison to Other Database Engines</h2> <table><tr> <th>Feature</th> <th>H2</th> <th>Derby</th> <th>HSQLDB</th> <th>MySQL</th> <th>PostgreSQL</th> </tr><tr> <td>Embedded Mode (Java)</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> <td class="compareN">No</td> <td class="compareN">No</td> </tr><tr> <td>Pure Java</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> <td class="compareN">No</td> <td class="compareN">No</td> </tr><tr> <td>Performance (Embedded)</td> <td class="compareY">Fast</td> <td class="compareN">Slow</td> <td class="compareY">Fast</td> <td class="compareN">N/A</td> <td class="compareN">N/A</td> </tr><tr> <td>Transaction Isolation</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> <td class="compareN">No</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> </tr><tr> <td>Cost Based Optimizer</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> <td class="compareN">No</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> </tr><tr> <td>Clustering</td> <td class="compareY">Yes</td> <td class="compareN">No</td> <td class="compareN">No</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> </tr><tr> <td>Encrypted Database</td> <td class="compareY">Yes</td> <td class="compareY">Yes</td> <td class="compareN">No</td> <td class="compareN">No</td> <td class="compareN">No</td> </tr><tr> <td>Files per Database</td> <td class="compareY">Few</td> <td class="compareN">Many</td> <td class="compareY">Few</td> <td class="compareN">Many</td> <td class="compareN">Many</td> </tr><tr> <td>Footprint (jar/dll size)</td> <td>~ 1 MB</td> <td>~ 2 MB</td> <td>~ 600 KB</td> <td>~ 4 MB</td> <td>~ 6 MB</td> </tr> </table> <h3>Derby and HSQLDB</h3> <p> After an unexpected process termination (for example power failure), H2 can recover safely and automatically without any user interaction. For Derby and HSQLDB, there are some manual steps required ('Another instance of Derby may have already booted the database' / 'The database is already in use by another process'). </p> <h3>DaffodilDb and One$Db</h3> <p> It looks like the development of this database has stopped. The last release was February 2006. </p> <h3>McKoi</h3> <p> It looks like the development of this database has stopped. The last release was August 2004 </p> <br /><a name="products_work_with"></a> <h2>H2 in Use</h2> <p> For a list of applications that work with or use H2, see: <a href="http://groups.google.com/group/h2-database/web/h2-in-use"> http://groups.google.com/group/h2-database/web/h2-in-use </a> </p> <br /><a name="connection_modes"></a> <h2>Connection Modes</h2> <p> The following connection modes are supported: </p> <ul> <li>Local connections using JDBC (embedded) </li><li>Remote connections using JDBC over TCP/IP (client/server) </li><li>Remote connections using ODBC over TCP/IP (client/server) </li><li>In-Memory databases (private and shared) </li></ul> <br /><a name="database_url"></a> <h2>Database URL Overview</h2> <p> This database does support multiple connection modes and features when connecting to a database. This is achieved using different database URLs. The settings in the URLs are not case sensitive. </p> <table><tr><th>Topic</th><th>URL Format and Examples</th></tr> <tr> <td>Embedded (local) connection</td> <td> jdbc:h2:[file:][<path>]<databaseName><br /> jdbc:h2:~/test<br /> jdbc:h2:file:/data/sample<br /> jdbc:h2:file:C:/data/sample (Windows only)<br /> </td> </tr> <tr> <td>In-Memory (private)</td> <td>jdbc:h2:mem:</td> </tr> <tr> <td>In-Memory (named)</td> <td> jdbc:h2:mem:<databaseName><br /> jdbc:h2:mem:test_mem </td> </tr> <tr> <td>Remote using TCP/IP</td> <td> jdbc:h2:tcp://<server>[:<port>]/<databaseName><br /> jdbc:h2:tcp://localhost/test<br /> jdbc:h2:tcp://dbserv:8084/sample </td> </tr> <tr> <td>Remote using SSL/TLS</td> <td> jdbc:h2:ssl://<server>[:<port>]/<databaseName><br /> jdbc:h2:ssl://secureserv:8085/sample; </td> </tr> <tr> <td>Using Encrypted Files</td> <td> jdbc:h2:<url>;CIPHER=[AES|XTEA]<br /> jdbc:h2:ssl://secureserv/testdb;CIPHER=AES<br /> jdbc:h2:file:~/secure;CIPHER=XTEA<br /> </td> </tr> <tr> <td>File Locking Methods</td> <td> jdbc:h2:<url>;FILE_LOCK={NO|FILE|SOCKET}<br /> jdbc:h2:file:~/quickAndDirty;FILE_LOCK=NO<br /> jdbc:h2:file:~/private;CIPHER=XTEA;FILE_LOCK=SOCKET<br /> </td> </tr> <tr> <td>Only Open if it Already Exists</td> <td> jdbc:h2:<url>;IFEXISTS=TRUE<br /> jdbc:h2:file:~/sample;IFEXISTS=TRUE<br /> </td> </tr> <tr> <td>Don't Close the Database when the VM Exits</td> <td> jdbc:h2:<url>;DB_CLOSE_ON_EXIT=FALSE </td> </tr> <tr> <td>User Name and/or Password</td> <td> jdbc:h2:<url>[;USER=<username>][;PASSWORD=<value>]<br /> jdbc:h2:file:~/sample;USER=sa;PASSWORD=123<br /> </td> </tr> <tr> <td>Log Index Changes</td> <td> jdbc:h2:<url>;LOG=2<br /> jdbc:h2:file:~/sample;LOG=2<br /> </td> </tr> <tr> <td>Debug Trace Settings</td> <td> jdbc:h2:<url>;TRACE_LEVEL_FILE=<level 0..3><br /> jdbc:h2:file:~/sample;TRACE_LEVEL_FILE=3<br /> </td> </tr> <tr> <td>Ignore Unknown Settings</td> <td> jdbc:h2:<url>;IGNORE_UNKNOWN_SETTINGS=TRUE<br /> </td> </tr> <tr> <td>Custom File Access Mode</td> <td> jdbc:h2:<url>;ACCESS_MODE_LOG=rws;ACCESS_MODE_DATA=rws<br /> </td> </tr> <tr> <td>In-Memory (private)</td> <td>jdbc:h2:mem:</td> </tr> <tr> <td>Database in Jar or Zip File</td> <td> jdbc:h2:zip:<zipFileName>!/<databaseName><br /> jdbc:h2:zip:db.zip!/test </td> </tr> <tr> <td>Changing Other Settings</td> <td> jdbc:h2:<url>;<setting>=<value>[;<setting>=<value>...]<br /> jdbc:h2:file:~/sample;TRACE_LEVEL_SYSTEM_OUT=3<br /> </td> </tr> </table> <h3>Connecting to an Embedded (Local) Database</h3> <p> The database URL for connecting to a local database is <code>jdbc:h2:[file:][<path>]<databaseName></code>. The prefix <code>file:</code> is optional. If no or only a relative path is used, then the current working directory is used as a starting point. The case sensitivity of the path and database name depend on the operating system, however it is suggested to use lowercase letters only. The database name must be at least three characters long (a limitation of File.createTempFile). To point to the user home directory, use ~/, as in: jdbc:h2:~/test. </p> <h3>Memory-Only Databases</h3> <p> For certain use cases (for example: rapid prototyping, testing, high performance operations, read-only databases), it may not be required to persist (changes to) the data at all. This database supports the memory-only mode, where the data is not persisted. </p><p> In some cases, only one connection to a memory-only database is required. This means the database to be opened is private. In this case, the database URL is <code>jdbc:h2:mem:</code> Opening two connections within the same virtual machine means opening two different (private) databases. </p><p> Sometimes multiple connections to the same memory-only database are required. In this case, the database URL must include a name. Example: <code>jdbc:h2:mem:db1</code>. Accessing the same database in this way only works within the same virtual machine and class loader environment. </p><p> It is also possible to access a memory-only database remotely (or from multiple processes in the same machine) using TCP/IP or SSL/TLS. An example database URL is: <code>jdbc:h2:tcp://localhost/mem:db1</code> (using private database remotely is also possible). </p> <br /><a name="file_encryption"></a> <h2>Connecting to a Database with File Encryption</h2> <p> To use file encryption, it is required to specify the encryption algorithm (the 'cipher') and the file password. The algorithm needs to be specified using the connection parameter. Two algorithms are supported: XTEA and AES. The file password is specified in the password field, before the user password. A single space needs to be added between the file password and the user password; the file password itself may not contain spaces. File passwords (as well as user passwords) are case sensitive. Here is an example to connect to a password encrypted database: </p> <pre> Class.forName("org.h2.Driver"); String url = "jdbc:h2:~/test;CIPHER=AES"; String user = "sa"; String pwds = "filepwd userpwd"; conn = DriverManager. getConnection(url, user, pwds); </pre> <br /><a name="database_file_locking"></a> <h2>Database File Locking</h2> <p> Whenever a database is opened, a lock file is created to signal other processes that the database is in use. If database is closed, or if the process that opened the database terminates, this lock file is deleted. </p><p> The following file locking methods are implemented: </p> <ul> <li>The default method is 'file' and uses a watchdog thread to protect the database file. The watchdog reads the lock file each second. </li><li>The second method is 'socket' and opens a server socket. The socket method does not require reading the lock file every second. The socket method should only be used if the database files are only accessed by the one (and always the same) computer. </li><li>It is also possible to open the database without file locking; in this case it is up to the application to protect the database files. </li></ul> <p> To open the database with a different file locking method, use the parameter 'FILE_LOCK'. The following code opens the database with the 'socket' locking method: <pre> String url = "jdbc:h2:~/test;FILE_LOCK=SOCKET"; </pre> The following code forces the database to not create a lock file at all. Please note that this is unsafe as another process is able to open the same database, possibly leading to data corruption: <pre> String url = "jdbc:h2:~/test;FILE_LOCK=NO"; </pre> For more information about the algorithms please see in Advanced Topics under File Locking Protocol. </p> <br /><a name="database_only_if_exists"></a> <h2>Opening a Database Only if it Already Exists</h2> <p> By default, when an application calls <code>DriverManager.getConnection(url,...)</code> and the database specified in the URL does not yet exist, a new (empty) database is created. In some situations, it is better to restrict creating new database, and only open the database if it already exists. This can be done by adding <code>;ifexists=true</code> to the URL. In this case, if the database does not already exist, an exception is thrown when trying to connect. The connection only succeeds when the database already exists. The complete URL may look like this: </p> <pre> String url = "jdbc:h2:/data/sample;IFEXISTS=TRUE"; </pre> <br /><a name="closing_the_database"></a> <h2>Closing the Database</h2> <h3>Delayed Database Closing</h3> <p> Usually, the database is closed when the last connection to it is closed. In some situations this slows down the application, for example when it is not possible leave the connection open. The automatic closing of the database can be delayed or disabled with the SQL statement SET DB_CLOSE_DELAY <seconds>. The seconds specifies the number of seconds to keep a database open after the last connection to it was closed. For example the following statement will keep the database open for 10 seconds: <pre> SET DB_CLOSE_DELAY 10 </pre> The value -1 means the database is never closed automatically. The value 0 is the default and means the database is closed when the last connection is closed. This setting is persistent and can be set by an administrator only. It is possible to set the value in the database URL: <code>jdbc:h2:~/test;DB_CLOSE_DELAY=10</code>. </p> <h3>Don't Close the Database when the VM Exits</h3> <p> By default, a database is closed when the last connection is closed. However, if it is never closed, the database is closed when the virtual machine exits normally. This is done using a shutdown hook. In some situations, the database should not be closed in this case, for example because the database is still used at virtual machine shutdown (to store the shutdown process in the database for example). For those cases, the automatic closing of the database can be disabled in the database URL. The first connection (the one that is opening the database) needs to set the option in the database URL (it is not possible to change the setting afterwards). The database URL to disable database closing on exit is: </p> <pre> String url = "jdbc:h2:~/test;DB_CLOSE_ON_EXIT=FALSE"; </pre> <br /><a name="log_index_changes"></a> <h2>Log Index Changes</h2> <p> Usually, changes to the index file are not logged for performance. If the index file is corrupt or missing when opening a database, it is re-created from the data. The index file can get corrupt when the database is not shut down correctly, because of power failure or abnormal program termination. In some situations, for example when using very large databases (over a few hundred MB), re-creating the index file takes very long. In these situations it may be better to log changes to the index file, so that recovery from a corrupted index file is fast. To enable log index changes, add LOG=2 to the URL, as in jdbc:h2:~/test;LOG=2 This setting should be specified when connecting. The update performance of the database will be reduced when using this option. </p> <h3>Ignore Unknown Settings</h3> <p> Some applications (for example OpenOffice.org Base) pass some additional parameters when connecting to the database. Why those parameters are passed is unknown. The parameters PREFERDOSLIKELINEENDS and IGNOREDRIVERPRIVILEGES are such examples, they are simply ignored to improve the compatibility with OpenOffice.org. If an application passes other parameters when connecting to the database, usually the database throws an exception saying the parameter is not supported. It is possible to ignored such parameters by adding ;IGNORE_UNKNOWN_SETTINGS=TRUE to the database URL. </p> <h3>Changing Other Settings when Opening a Connection</h3> <p> In addition to the settings already described (cipher, file_lock, ifexists, user, password), other database settings can be passed in the database URL. Adding <code>setting=value</code> at the end of an URL is the same as executing the statement <code>SET setting value</code> just after connecting. For a list of settings supported by this database please see the SQL grammar documentation. </p> <br /><a name="custom_access_mode"></a> <h2>Custom File Access Mode</h2> <p> Usually, the database opens log, data and index files with the access mode 'rw', meaning read-write (except for read only databases, where the mode 'r' is used). Also supported are 'rws' and 'rwd'. The access mode used for log files is set via ACCESS_MODE_LOG; for data and index files use ACCESS_MODE_DATA. These settings must be specified in the database URL: <pre> String url = "jdbc:h2:~/test;ACCESS_MODE_LOG=rws;ACCESS_MODE_DATA=rws"; </pre> For more information see <a href="advanced.html#durability_problems">Durability Problems</a>. On many operating systems the access mode 'rws' does not guarantee that the data is written to the disk. </p> <br /><a name="multiple_connections"></a> <h2>Multiple Connections</h2> <h3>Opening Multiple Databases at the Same Time</h3> <p> An application can open multiple databases at the same time, including multiple connections to the same database. The number of open database is only limited by the memory available. </p> <h3>Multiple Connections to the Same Database: Client/Server</h3> <p> If you want to access the same database at the same time from different processes or computers, you need to use the client / server mode. In this case, one process acts as the server, and the other processes (that could reside on other computers as well) connect to the server via TCP/IP (or SSL/TLS over TCP/IP for improved security). </p> <h3>Multithreading Support</h3> <p> This database is multithreading-safe. That means, if an application is multi-threaded, it does not need o worry about synchronizing the access to the database. Internally, most requests to the same database are synchronized. That means an application can use multiple threads all accessing the same database at the same time, however if one thread executes a long running query, the other threads need to wait. </p> <h3>Locking, Lock-Timeout, Deadlocks</h3> <p> The database uses table level locks to give each connection a consistent state of the data. There are two kinds of locks: read locks (shared locks) and write locks (exclusive locks). If a connection wants to reads from a table, and there is no write lock on the table, then a read lock is added to the table. If there is a write lock, then this connection waits for the other connection to release the lock. If connection cannot get a lock for a specified time, then a lock timeout exception is thrown. </p><p> Usually, SELECT statement will generate read locks. This includes subqueries. Statements that modify data use write locks. It is also possible to lock a table exclusively without modifying data, using the statement SELECT ... FOR UPDATE. The statements COMMIT and ROLLBACK releases all open locks. The commands SAVEPOINT and ROLLBACK TO SAVEPOINT don't affect locks. The locks are also released when the autocommit mode changes, and for connections with autocommit set to true (this is the default), locks are released after each statement. Here is an overview on what statements generate what type of lock: </p> <table><tr><th>Type of Lock</th><th>SQL Statement</th></tr> <tr> <td> Read </td> <td> SELECT * FROM TEST<br /> CALL SELECT MAX(ID) FROM TEST<br /> SCRIPT </td> </tr> <tr> <td> Write </td> <td> SELECT * FROM TEST WHERE 1=0 FOR UPDATE </td> </tr> <tr> <td> Write </td> <td> INSERT INTO TEST VALUES(1, 'Hello')<br /> INSERT INTO TEST SELECT * FROM TEST<br /> UPDATE TEST SET NAME='Hi'<br /> DELETE FROM TEST </td> </tr> <tr> <td> Write </td> <td> ALTER TABLE TEST ...<br /> CREATE INDEX ... ON TEST ...<br /> DROP INDEX ... </td> </tr> </table> <p> The number of seconds until a lock timeout exception is thrown can be set separately for each connection using the SQL command SET LOCK_TIMEOUT <milliseconds>. The initial lock timeout (that is the timeout used for new connections) can be set using the SQL command SET DEFAULT_LOCK_TIMEOUT <milliseconds>. The default lock timeout is persistent. </p> <br /><a name="database_file_layout"></a> <h2>Database File Layout</h2> <p> There are a number of files created for persistent databases. Other than some databases, not every table and/or index is stored in its own file. Instead, usually only the following files are created: A data file, an index file, a log file, and a database lock file (exists only while the database is in use). In addition to that, a file is created for each large object (CLOB/BLOB), a file for each linear index, and temporary files for large result sets. Then the command SCRIPT can create script files. If the database trace option is enabled, trace files are created. The following files can be created by the database: </p> <table><tr><th>File Name</th><th>Description</th><th>Number of Files</th></tr> <tr><td> test.data.db </td><td> Data file<br /> Contains the data for all tables<br /> Format: <database>.data.db </td><td> 1 per database </td></tr> <tr><td> test.index.db </td><td> Index file<br /> Contains the data for all (btree) indexes<br /> Format: <database>.index.db </td><td> 1 per database </td></tr> <tr><td> test.0.log.db </td><td> Log file<br /> The log file is used for recovery<br /> Format: <database>.<id>.log.db </td><td> 0 or more per database </td></tr> <tr><td> test.lock.db </td><td> Database lock file<br /> Exists only if the database is open<br /> Format: <database>.lock.db </td><td> 1 per database </td></tr> <tr><td> test.trace.db </td><td> Trace file<br /> Contains trace information<br /> Format: <database>.trace.db<br /> If the file is too big, it is renamed to <database>.trace.db.old </td><td> 1 per database </td></tr> <tr><td> test.14.15.lob.db </td><td> Large object<br /> Contains the data for BLOB or CLOB<br /> Format: <database>.<tableid>.<id>.lob.db </td><td> 1 per object </td></tr> <tr><td> test.123.temp.db </td><td> Temporary file<br /> Contains a temporary blob or a large result set<br /> Format: <database>.<session id>.<object id>.temp.db </td><td> 1 per object </td></tr> <tr><td> test.7.hash.db </td><td> Hash index file<br /> Contains the data for a linear hash index<br /> Format: <database>.<object id>.hash.db </td><td> 1 per linear hash index </td></tr> </table> <h3>Moving and Renaming Database Files</h3> <p> Database name and location are not stored inside the database names. </p><p> While a database is closed, the files can be moved to another directory, and they can be renamed as well (as long as all files start with the same name). </p><p> As there is no platform specific data in the files, they can be moved to other operating systems without problems. </p> <h3>Backup</h3> <p> When the database is closed, it is possible to backup the database files. Please note that index files do not need to be backed up, because they contain redundant data, and will be recreated automatically if they don't exist. </p><p> To backup data while the database is running, the SQL command SCRIPT can be used. </p> <br /><a name="logging_recovery"></a> <h2>Logging and Recovery</h2> <p> Whenever data is modified in the database and those changes are committed, the changes are logged to disk (except for in-memory objects). The changes to the data file itself are usually written later on, to optimize disk access. If there is a power failure, the data and index files are not up-to-date. But because the changes are in the log file, the next time the database is opened, the changes that are in the log file are re-applied automatically. </p><p> Please note that index file updates are not logged by default. If the database is opened and recovery is required, the index file is rebuilt from scratch. </p><p> There is usually only one log file per database. This file grows until the database is closed successfully, and is then deleted. Or, if the file gets too big, the database switches to another log file (with a higher id). It is possible to force the log switching by using the CHECKPOINT command. </p><p> If the database file is corrupted, because the checksum of a record does not match (for example, if the file was edited with another application), the database can be opened in recovery mode. In this case, errors in the database are logged but not thrown. The database should be backed up to a script and re-built as soon as possible. To open the database in the recovery mode, use a database URL must contain RECOVER=1, as in jdbc:h2:~/test;RECOVER=1. Indexes are rebuilt in this case, and the summary (object allocation table) is not read in this case, so opening the database takes longer. </p> <br /><a name="compatibility_modes"></a> <h2>Compatibility Modes</h2> <p> All database engines behave a little bit different. For certain features, this database can emulate the behavior of specific databases. Not all features or differences of those databases are implemented. Currently, this feature is mainly used for randomized comparative testing (where random statements are executed against multiple databases and the results are compared). The mode can be changed by specifying the mode in the database URL, or using the SQL statement SET MODE. To use the HSQLDB mode, you can use the database URL <code>jdbc:h2:~/test;MODE=HSQLDB</code> or the SQL statement <code>SET MODE HSQLDB</code>. Here is the list of currently supported modes and the difference to the regular mode: </p> <table> <tr><th>Mode</th><th>Differences</th></tr> <tr><td> PostgreSQL </td><td> Concatenation of a NULL with another value results in NULL. Usually, the NULL is treated as an empty string if only one of the operators is NULL, and NULL is only returned if both values are NULL. </td></tr> <tr><td> MySQL </td><td> When inserting data, if a column is defined to be NOT NULL and NULL is inserted, then a 0 (or empty string, or the current timestamp for timestamp columns) value is used. Usually, this operation is not allowed and an exception is thrown. </td></tr> <tr><td> HSQLDB </td><td> When converting the scale of decimal data, the number is only converted if the new scale is smaller then current scale. Usually, the scale is converted and 0s are added if required. </td></tr> </table> <br /><a name="trace_options"></a> <h2>Using the Trace Options</h2> <p> To find problems in an application, it is sometimes good to see what database operations where executed. This database offers the following trace features: </p> <ul> <li>Trace to System.out and/or a file </li><li>Support for trace levels OFF, ERROR, INFO, and DEBUG </li><li>The maximum size of the trace file can be set </li><li>The Java code generation is possible </li><li>Trace can be enabled at runtime by manually creating a file </li></ul> <h3>Trace Options</h3> <p> The simplest way to enable the trace option is setting it in the database URL. There are two settings, one for System.out (TRACE_LEVEL_SYSTEM_OUT) tracing, and one for file tracing (TRACE_LEVEL_FILE). The trace levels are 0 for OFF, 1 for ERROR (the default), 2 for INFO and 3 for DEBUG. A database URL with both levels set to DEBUG is: <pre> jdbc:h2:~/test;TRACE_LEVEL_FILE=3;TRACE_LEVEL_SYSTEM_OUT=3 </pre> The trace level can be changed at runtime by executing the SQL command <code>SET TRACE_LEVEL_SYSTEM_OUT level</code> (for System.out tracing) or <code>SET TRACE_LEVEL_FILE level</code> (for file tracing). Example: <pre> SET TRACE_LEVEL_SYSTEM_OUT 3 </pre> </p> <h3>Setting the Maximum Size of the Trace File</h3> <p> When using a high trace level, the trace file can get very big quickly. The size of the file can be limited by executing the SQL statement <code>SET TRACE_MAX_FILE_SIZE maximumFileSizeInMB</code>. If the log file exceeds the limit, the file is renamed to .old and a new file is created. If another .old file exists, it is deleted. The default setting is 16 MB. Example: </p> <pre> SET TRACE_MAX_FILE_SIZE 1 </pre> <h3>Java Code Generation</h3> <p> When setting the trace level to INFO or DEBUG, Java source code is generated as well, so that problem can be reproduced more easily. The trace file looks like this: <pre> ... 12-20 20:58:09 jdbc[0]: /**/dbMeta3.getURL(); 12-20 20:58:09 jdbc[0]: /**/dbMeta3.getTables(null, "", null, new String[]{"TABLE", "VIEW"}); ... </pre> You need to filter out the lines without /**/ to get the Java source code. In Windows, a simple way to do that is: <pre> find "**" test.trace.db > Trace.java </pre> Afterwards, you need to complete the file Trace.java before it can be compiled, for example with: <pre> import java.sql.*; public class Trace { public static void main(String[]a)throws Exception { Class.forName("org.h2.Driver"); ... }} </pre> Also, the user name and password needs to be set, because they are not listed in the trace file. </p> <h3>Enabling the Trace Option at Runtime by Manually Creating a File</h3> <p> Sometimes, you can't or don't want to change the application or database URL. There is still a way to enable the trace mode in these cases, even at runtime (while the database connection is open). You only need to create a special file in the directory where the database files are stored. The database engine checks every 4 seconds if this file exists (only while executing a statement). The file name is the database name plus '.trace.db.start'. This feature is disabled if the database is encrypted. </p><p> Example: if a database is called 'test', then the file to start tracing is 'test.trace.db.start'. The database engine tries to delete this file when it detects it. If trace is enabled using the start file, the trace level is not persistent to the database, and trace is switched back to the level that was set before when connecting to the database. However, if the start file is read only, the database engine cannot delete the file and will always enable the trace mode when connecting. </p> <br /><a name="read_only"></a> <h2>Read Only Databases</h2> <p> If the database files are read-only, then the database is read-only as well. It is not possible to create new tables, add or modify data in this database. Only SELECT statements are allowed. To create a read-only database, close the database so that the log file gets smaller. Do not delete the log file. Then, make the database files read-only using the operating system. When you open the database now, it is read-only. There are two ways an application can find out a database is read-only: By calling Connection.isReadOnly() or by executing the SQL statement CALL READONLY(). </p> <br /><a name="storage_formats"></a> <h2>Binary and Text Storage Formats</h2> <p> This database engine supports both binary and text storage formats. The binary format is faster, but the text storage format can be useful as well, for example to debug the database engine. If a database already exists, the storage format is recognized automatically. New databases are created in the binary storage format by default. To create a new database in the text storage format, the database URL must contain the parameter STORAGE=TEXT. Example URL: jdbc:h2:~/test;STORAGE=TEXT </p> <br /><a name="low_disk_space"></a> <h2>Graceful Handling of Low Disk Space Situations</h2> <p> The database is able to deal with situations where the disk space available is running low. Whenever the database starts, an 'emergency space' file is created (size is 1 MB), and if there is no more space available, the file will shrink. If the space available is lower than 128 KB, the database will go into a special read only mode, where writing operations are no longer allowed: All writing operations will throw the exception 'No disk space available' from this point on. To go back to the normal operating mode, all connections to the database need to be closed first, and space needs to be freed up. </p><p> It is possible to install a database event listener to detect low disk space situations early on (when only 1 MB if space is available). To do this, use the SQL statement SET DATABASE_EVENT_LISTENER. The listener can also be set at connection time, using an URL of the form jdbc:h2:~/test;DATABASE_EVENT_LISTENER='com.acme.DbListener' (the quotes around the class name are required). See also the DatabaseEventListener API. </p> <h3>Opening a Corrupted Database</h3> <p> If a database can not be opened because the boot info (the SQL script that is run at startup) is corrupted, then the database can be opened by specifying a database event listener. The exceptions are logged, but opening the database will continue. </p> <br /><a name="computed_columns"></a> <h2>Computed Columns / Function Based Index</h2> <p> Function indexes are not directly supported by this database, but they can be easily emulated by using computed columns. For example, if an index on the upper-case version of a column is required, just create a computed column with the upper-case version of the original column, and index this column: <pre> CREATE TABLE ADDRESS( ID INT PRIMARY KEY, NAME VARCHAR, UPPER_NAME VARCHAR AS UPPER(NAME) ); CREATE INDEX IDX_U_NAME ON ADDRESS(UPPER_NAME); </pre> When inserting data, it is not required (better: not allowed) to specify a value for the upper-case version of the column, because the value is generated. But you can use the column when querying the table: <pre> INSERT INTO ADDRESS(ID, NAME) VALUES(1, 'Miller'); SELECT * FROM ADDRESS WHERE UPPER_NAME='MILLER'; </pre> </p> <br /><a name="multi_dimensional"></a> <h2>Multi-Dimensional Indexes</h2> <p> A tool is provided to execute efficient multi-dimension (spatial) range queries. This database does not support a specialized spatial index (R-Tree or similar). Instead, the B-Tree index is used. For each record, the multi-dimensional key is converted (mapped) to a single dimensional (scalar) value. This value specifies the location on a space-filling curve. </p><p> Currently, Z-order (also called N-order or Morton-order) is used; Hilbert curve could also be used, but the implementation is more complex. The algorithm to convert the multi-dimensional value is called bit-interleaving. The scalar value is indexed using a B-Tree index (usually using a computed column). </p><p> The method can result in a drastic performance improvement over just using an index on the first column. Depending on the data and number of dimensions, the improvement is usually higher than factor 5. The tool generates a SQL query from a specified multi-dimensional range. The method used is not database dependent, and the tool can easily be ported to other databases. For an example how to use the tool, please have a look at the sample code provided in TestMultiDimension.java. </p> <br /><a name="passwords"></a> <h2>Using Passwords</h2> <h3>Using Secure Passwords</h3> <p> Remember that weak passwords can be broken no matter of the encryption and security protocol. Don't use passwords that can be found in a dictionary. Also appending numbers does not make them secure. A way to create good passwords that can be remembered is, take the first letters of a sentence, use upper and lower case characters, and creatively include special characters. Example: </p><p> i'sE2rtPiUKtT (it's easy to remember this password if you know the trick) </p> <h3>Passwords: Using Char Arrays instead of Strings</h3> <p> Java Strings are immutable objects and cannot be safely 'destroyed' by the application. After creating a String, it will remain in the main memory of the computer at least until it is garbage collected. The garbage collection cannot be controlled by the application, and even if it is garbage collected the data may still remain in memory. It might also be possible that the part of memory containing the password is swapped to disk (because not enough main memory is available). </p><p> An attacker might have access to the swap file of the operating system. It is therefore a good idea to use char arrays instead of Strings to store passwords. Char arrays can be cleared (filled with zeros) after use, and therefore the password will not be stored in the swap file. </p><p> This database supports using char arrays instead of String to pass user and file passwords. The following code can be used to do that: <pre> Class.forName("org.h2.Driver"); String url = "jdbc:h2:simple"; String user = "sam"; char[] password = {'t','i','a','S','&',E','t','r','p'}; Properties prop = new Properties(); prop.setProperty("user", user); prop.put("password", password); Connection conn = null; try { conn = DriverManager. getConnection(url, prop); } finally { Arrays.fill(password, 0); } </pre> In this example, the password is hard code in the application, which is not secure of course. However, Java Swing supports a way to get passwords using a char array (JPasswordField). </p> <h3>Passing the User Name and/or Password in the URL</h3> <p> Instead of passing the user name as a separate parameter as in <code> Connection conn = DriverManager. getConnection("jdbc:h2:~/test", "sa", "123"); </code> the user name (and/or password) can be supplied in the URL itself: <code> Connection conn = DriverManager. getConnection("jdbc:h2:~/test;USER=sa;PASSWORD=123"); </code> The settings in the URL override the settings passed as a separate parameter. </p> <br /><a name="user_defined_functions"></a> <h2>User Defined Functions and Stored Procedures</h2> <p> In addition to the built-in functions, this database supports user defined Java functions. In this database, Java functions can be used as stored procedures as well. A function must be declared (registered) before it can be used. Only static Java methods are supported; both the class and the method must be public. Example Java method: <pre> package org.h2.samples; ... public class Function { public static boolean isPrime(int value) { return new BigInteger(String.valueOf(value)).isProbablePrime(100); } } </pre> The Java function must be registered in the database by calling CREATE ALIAS: <pre> CREATE ALIAS IS_PRIME FOR "org.h2.samples.Function.isPrime" </pre> For a complete sample application, see src/test/org/h2/samples/Function.java. </p> <h3>Function Data Type Mapping</h3> <p> Functions that accept non-nullable parameters such as 'int' will not be called if one of those parameters is NULL. In this case, the value NULL is used as the result. If the function should be called in this case, you need to use 'java.lang.Integer' instead of 'int'. </p> <h3>Functions that require a Connection</h3> <p> If the first parameter in a Java function is a java.sql.Connection, then the connection to database is provided. This connection does not need to be closed before returning. </p> <h3>Functions throwing an Exception</h3> <p> If a function throws an Exception, then the current statement is rolled back and the exception is thrown to the application. </p> <h3>Functions returning a Result Set</h3> <p> Functions may returns a result set. Such a function can be called with the CALL statement: <pre> public static ResultSet query(Connection conn, String sql) throws SQLException { return conn.createStatement().executeQuery(sql); } CREATE ALIAS QUERY FOR "org.h2.samples.Function.query"; CALL QUERY('SELECT * FROM TEST'); </pre> </p> <h3>Using SimpleResultSet</h3> <p> A function that returns a result set can create this result set from scratch using the SimpleResultSet tool: <pre> import org.h2.tools.SimpleResultSet; ... public static ResultSet simpleResultSet() throws SQLException { SimpleResultSet rs = new SimpleResultSet(); rs.addColumn("ID", Types.INTEGER, 10, 0); rs.addColumn("NAME", Types.VARCHAR, 255, 0); rs.addRow(new Object[] { new Integer(0), "Hello" }); rs.addRow(new Object[] { new Integer(1), "World" }); return rs; } CREATE ALIAS SIMPLE FOR "org.h2.samples.Function.simpleResultSet"; CALL SIMPLE(); </pre> </p> <h3>Using a Function as a Table</h3> <p> A function returning a result set can be like a table. However, in this case the function is called at least twice: First while parsing the statement to collect the column names (with parameters set to null where not known at compile time). And then, while executing the statement to get the data (may be repeatedly if this is a join). If the function is called just to get the column list, the URL of the connection passed to the function is jdbc:columnlist:connection. Otherwise, the URL of the connection is jdbc:default:connection. <pre> public static ResultSet getMatrix(Integer id) throws SQLException { SimpleResultSet rs = new SimpleResultSet(); rs.addColumn("X", Types.INTEGER, 10, 0); rs.addColumn("Y", Types.INTEGER, 10, 0); if(id == null) { return rs; } for(int x = 0; x < id.intValue(); x++) { for(int y = 0; y < id.intValue(); y++) { rs.addRow(new Object[] { new Integer(x), new Integer(y) }); } } return rs; } CREATE ALIAS MATRIX FOR "org.h2.samples.Function.getMatrix"; SELECT * FROM MATRIX(3) WHERE X>0; </pre> </p> <br /><a name="triggers"></a> <h2>Triggers</h2> <p> This database supports Java triggers that are called before or after a row is updated, inserted or deleted. Triggers can be used for complex consistency checks, or to update related data in the database. It is also possible to use triggers to simulate materialized views. For a complete sample application, see src/test/org/h2/samples/TriggerSample.java. A Java trigger must implement the interface org.h2.api.Trigger: <pre> import org.h2.api.Trigger; ... public class TriggerSample implements Trigger { public void init(String triggerName, String tableName) { } public void fire(Connection conn, Object[] oldRow, Object[] newRow) throws SQLException { } } </pre> The connection can be used to query or update data in other tables. The trigger then needs to be defined in the database: <pre> CREATE TRIGGER INV_INS AFTER INSERT ON INVOICE FOR EACH ROW CALL "org.h2.samples.TriggerSample" </pre> The trigger can be used to veto a change, by throwing a SQL Exception. </p> <br /><a name="compacting"></a> <h2>Compacting a Database</h2> <p> Empty space in the database file is re-used automatically. To re-build the indexes, the most simple way is to delete the .index.db file while the database is closed. However in some situations (for example after deleting a lot of data in a database), one sometimes wants to shrink the size of the database (compact a database). Here is a sample function to do this: <pre> public static void compact(String dir, String dbName, String user, String password) throws Exception { String url = "jdbc:h2:" + dir + "/" + dbName; String file = "data/test.sql"; Script.execute(url, user, password, file); DeleteDbFiles.execute(dir, dbName, true); RunScript.execute(url, user, password, file, null, false); } </pre> See also the sample application org.h2.samples.Compact. The commands SCRIPT / RUNSCRIPT can be used as well to create the a backup of a database and re-build the database from the script. </p> <br /><a name="cache_settings"></a> <h2>Cache Settings</h2> <p> The database keeps most frequently used data and index pages in the main memory. The amount of memory used for caching can be changed using the setting CACHE_SIZE. This setting can be set in the database connection URL (jdbc:h2:~/test;CACHE_SIZE=131072), or it can be changed at runtime using SET CACHE_SIZE size. </p><p> This database supports two cache page replacement algorithms: LRU (the default) and 2Q. For LRU, the pages that were least frequently used are removed from the cache if it becomes full. The 2Q algorithm is a bit more complicated, basically two queues are used. The 2Q algorithm is more resistant to table scans, however the overhead is a bit higher compared to the LRU. To use the cache algorithm 2Q, use a database URL of the form jdbc:h2:~/test;CACHE_TYPE=TQ. The cache algorithm can not be changed once the database is open. </p><p> To get information about page reads and writes, and the current caching algorithm in use, call SELECT * FROM INFORMATION_SCHEMA.SETTINGS. The number of pages read / written is listed for the data and index file. </p> <br /><a name="why_java"></a> <h2>Why Java</h2> <p> A few reasons using a Java database are: </p> <ul> <li>Very simple to integrate in Java applications </li><li>Support for many different platforms </li><li>More secure than native applications (no buffer overflows) </li><li>User defined functions (or triggers) run very fast </li><li>Unicode support </li></ul> <p> Some people think that Java is still too slow for low level operations, but this is not the case (not any more). In general, the code can be written a lot faster than using C or C++. Like that, it is possible to concentrate on improving the algorithms (that make the application faster) rather than porting the code and dealing with low level stuff (such as memory management or dealing with threads). Garbage collection is now probably faster than manual memory management. </p><p> A lot of features are already built in (for example Unicode, network libraries). It is very easy to write secure code because buffer overflows and such problems can be detected very easily. Some features such as the reflection mechanism can be used for randomized testing. </p><p> Java is also future proof: A lot of companies support Java, and it is now open source. </p><p> This software does not rely on many Java libraries or other software, to increase the portability and ease of use, and for performance reasons. For example, the encryption algorithms and many library functions are implemented in the database instead of using the existing libraries. Libraries that are not available in open source Java implementations (such as Swing) are not used or only used for specific features. </p> </div></td></tr></table></body></html>