FeaturesFeature ListComparison to Other Database Engines H2 in Use Connection Modes Database URL Overview Connecting to an Embedded (Local) Database Memory-Only Databases Database Files Encryption Database File Locking Opening a Database Only if it Already Exists Closing a Database Ignore Unknown Settings Changing Other Settings when Opening a Connection Log Index Changes Custom File Access Mode Multiple Connections Database File Layout Logging and Recovery Compatibility Auto-Reconnect Automatic Mixed Mode Using the Trace Options Using Other Logging APIs Read Only Databases Read Only Databases in Zip or Jar File Graceful Handling of Low Disk Space Situations Computed Columns / Function Based Index Multi-Dimensional Indexes Using Passwords User-Defined Functions and Stored Procedures Triggers Compacting a Database Cache Settings Feature ListMain Features
Additional Features
SQL Support
Security Features
Other Features and Tools
Comparison to Other Database Engines
*1 HSQLDB supports text tables. Derby and HSQLDBAfter an unexpected process termination (for example power failure), H2 can recover safely and automatically without any user interaction. For Derby and HSQLDB, some manual steps are required ('Another instance of Derby may have already booted the database' / 'The database is already in use by another process'). DaffodilDb and One$DbIt looks like the development of this database has stopped. The last release was February 2006. McKoiIt looks like the development of this database has stopped. The last release was August 2004 H2 in UseFor a list of applications that work with or use H2, see: Links. Connection ModesThe following connection modes are supported:
Embedded ModeIn embedded mode, an application opens a database from within the same JVM using JDBC. This is the fastest and easiest connection mode. The disadvantage is that a database may only be open in one virtual machine (and class loader) at any time. As in all modes, both persistent and in-memory databases are supported. There is no limit on the number of database open concurrently, or on the number of open connections. ![]() Server ModeWhen using the server mode (sometimes called remote mode or client/server mode), an application opens a database remotely using the JDBC or ODBC API. A server needs to be started within the same or another virtual machine, or on another computer. Many applications can connect to the same database at the same time. The server mode is slower than the embedded mode, because all data is transferred over TCP/IP. As in all modes, both persistent and in-memory databases are supported. There is no limit on the number of database open concurrently, or on the number of open connections. ![]() Mixed ModeThe mixed mode is a combination of the embedded and the server mode. The first application that connects to a database does that in embedded mode, but also starts a server so that other applications (running in different processes or virtual machines) can concurrently access the same data. The local connections are as fast as if the database is used in just the embedded mode, while the remote connections are a bit slower. The server can be started and stopped from within the application (using the server API), or automatically (automatic mixed mode). When using the automatic mixed mode, all clients that want to connect to the database (no matter if it's an local or remote connection) can do so using the exact same database URL. ![]() Database URL OverviewThis database supports multiple connection modes and connection settings. This is achieved using different database URLs. Settings in the URLs are not case sensitive.
Connecting to an Embedded (Local) Database
The database URL for connecting to a local database is Memory-Only DatabasesFor certain use cases (for example: rapid prototyping, testing, high performance operations, read-only databases), it may not be required to persist data, or persist changes to the data. This database supports the memory-only mode, where the data is not persisted.
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
Sometimes multiple connections to the same memory-only database are required.
In this case, the database URL must include a name. Example:
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:
By default, closing the last connection to a database closes the database.
For an in-memory database, this means the content is lost.
To keep the database open, add ;DB_CLOSE_DELAY=-1 to the database URL.
To keep the content of an in-memory database as long as the virtual machine is alive, use
Database Files EncryptionThe database files can be encrypted. Two encryption algorithms are supported: AES and XTEA. To use file encryption, you need to specify the encryption algorithm (the 'cipher') and the file password (in addition to the user password) when connecting to the database. Creating a New Database with File EncryptionBy default, a new database is automatically created if it does not exist yet. To create an encrypted database, connect to it as it would already exist. Connecting to an Encrypted DatabaseThe encryption algorithm is set in the database URL, and the file password is specified in the password field, before the user password. A single space separates the file password and the user password; the file password itself may not contain spaces. File passwords and user passwords are case sensitive. Here is an example to connect to a password-encrypted database: 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); Encrypting or Decrypting a DatabaseTo encrypt an existing database, use the ChangeFileEncryption tool. This tool can also decrypt an encrypted database, or change the file encryption key. The tool is available from within the H2 Console in the Tools section, or you can run it from the command line. The following command line will encrypt the database 'test' in the user home directory with the file password 'filepwd' and the encryption algorithm AES: java -cp h2*.jar org.h2.tools.ChangeFileEncryption -dir ~ -db test -cipher AES -encrypt filepwd Database File LockingWhenever 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. The following file locking methods are implemented:
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: String url = "jdbc:h2:~/test;FILE_LOCK=SOCKET"; 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: String url = "jdbc:h2:~/test;FILE_LOCK=NO"; For more information about the algorithms, see Advanced / File Locking Protocols. Opening a Database Only if it Already Exists
By default, when an application calls String url = "jdbc:h2:/data/sample;IFEXISTS=TRUE"; Closing a DatabaseDelayed Database ClosingUsually, a 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 to keep at least one connection open. The automatic closing of a database can be delayed or disabled with the SQL statement SET DB_CLOSE_DELAY <seconds>. The parameter <seconds> specifies the number of seconds to keep a database open after the last connection to it was closed. The following statement will keep a database open for 10 seconds after the last connection was closed: SET DB_CLOSE_DELAY 10
The value -1 means the database is not 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: Don't Close a Database when the VM ExitsBy 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, 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: String url = "jdbc:h2:~/test;DB_CLOSE_ON_EXIT=FALSE"; Log Index Changes
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 Ignore Unknown SettingsSome 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. Changing Other Settings when Opening a Connection
In addition to the settings already described,
other database settings can be passed in the database URL.
Adding Custom File Access ModeUsually, 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). To open a database in read-only mode if the files are not read-only, use ACCESS_MODE_DATA=r. 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: String url = "jdbc:h2:~/test;ACCESS_MODE_LOG=rws;ACCESS_MODE_DATA=rws"; For more information see Durability Problems. On many operating systems the access mode 'rws' does not guarantee that the data is written to the disk. Multiple ConnectionsOpening Multiple Databases at the Same TimeAn 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. Multiple Connections to the Same Database: Client/ServerIf 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). Multithreading SupportThis database is multithreading-safe. That means, if an application is multi-threaded, it does not need to worry about synchronizing access to the database. Internally, most requests to the same database are synchronized. That means an application can use multiple threads that access the same database at the same time, however if one thread executes a long running query, the other threads need to wait. Locking, Lock-Timeout, DeadlocksThe 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). All locks are released when the transaction commits or rolls back. When using the default transaction isolation level 'read committed', read locks are already released after each statement. 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 a connection cannot get a lock for a specified time, then a lock timeout exception is thrown. Usually, SELECT statements 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. The following statements generate locks:
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. Database File LayoutThere are a number of files created for persistent databases. Unlike some other 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) larger than a certain size, and temporary files for large result sets. If the database trace option is enabled, trace files are created. The following files can be created by the database:
Moving and Renaming Database FilesDatabase name and location are not stored inside the database files. 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). As there is no platform specific data in the files, they can be moved to other operating systems without problems. BackupWhen 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. To backup data while the database is running, the SQL command SCRIPT can be used. Logging and RecoveryWhenever 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. 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. 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. 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. CompatibilityAll database engines behave a little bit different. Where possible, H2 supports the ANSI SQL standard, and tries to be compatible to other databases. There are still a few differences however:
In MySQL text columns are case insensitive by default, while in H2 they are case sensitive. However
H2 supports case insensitive columns as well. To create the tables with case insensitive texts, append
IGNORECASE=TRUE to the database URL (example: Compatibility ModesFor certain features, this database can emulate the behavior of specific databases. Not all features or differences of those databases are implemented. Here is the list of currently supported modes and the differences to the regular mode: DB2 Compatibility Mode
To use the IBM DB2 mode, use the database URL
Derby Compatibility Mode
To use the Apache Derby mode, use the database URL
HSQLDB Compatibility Mode
To use the HSQLDB mode, use the database URL
MS SQL Server Compatibility Mode
To use the MS SQL Server mode, use the database URL
MySQL Compatibility Mode
To use the MySQL mode, use the database URL
Oracle Compatibility Mode
To use the Oracle mode, use the database URL
PostgreSQL Compatibility Mode
To use the PostgreSQL mode, use the database URL
Auto-ReconnectThe auto-reconnect feature causes the JDBC driver to reconnect to the database if the connection is lost. The automatic re-connect only occurs when auto-commit is enabled; if auto-commit is disabled, an exception is thrown. Re-connecting will open a new session. After an automatic re-connect, variables and local temporary tables definitions (excluding data) are re-created. The contents of the system table INFORMATION_SCHEMA.SESSION_STATE contains all client side state that is re-created. Automatic Mixed Mode
Multiple processes can access the same database without having to start the server manually.
To do that, append When using this mode, the first connection to the database is made in embedded mode, and additionally a server is started internally. If the database is already open in another process, the server mode is used automatically. The application that opens the first connection to the database uses the embedded mode, which is faster than the server mode. Therefore the main application should open the database first if possible. The first connection automatically starts a server on a random port. This server allows remote connections, however only to this database (to ensure that, the client reads .lock.db file and sends the the random key that is stored there to the server). When the first connection is closed, the server stops. If other (remote) connections are still open, one of them will then start a server (auto-reconnect is enabled automatically). This mode has three disadvantages: all processes need to have access to the database files. Then, if the first connection is closed (the connection that started the server), open transactions of other connections will be rolled back. Also, explicit client/server connections (using jdbc:h2:tcp:// or ssl://) are not supported. Here is an example how to use this mode. Application 1 and 2 are not necessarily started on the same computer, but they need to have access to the database files. Application 1 and 2 are typically two different processes (however they could run within the same process). // Application 1: DriverManager.getConnection("jdbc:h2:/data/test;AUTO_SERVER=TRUE"); // Application 2: DriverManager.getConnection("jdbc:h2:/data/test;AUTO_SERVER=TRUE"); Using the Trace OptionsTo find problems in an application, it is sometimes good to see what database operations where executed. This database offers the following trace features:
Trace OptionsThe 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: jdbc:h2:~/test;TRACE_LEVEL_FILE=3;TRACE_LEVEL_SYSTEM_OUT=3
The trace level can be changed at runtime by executing the SQL command
SET TRACE_LEVEL_SYSTEM_OUT 3 Setting the Maximum Size of the Trace File
When using a high trace level, the trace file can get very big quickly.
The default size limit is 16 MB, if the trace file exceeds this limit, it is renamed to .old and a new file is created.
If another .old file exists, it is deleted.
The size limit can be changed using the SQL statement
SET TRACE_MAX_FILE_SIZE 1 Java Code GenerationWhen setting the trace level to INFO or DEBUG, Java source code is generated as well. This allows to reproduce problems more easily. The trace file looks like this: ... 12-20 20:58:09 jdbc[0]: /**/dbMeta3.getURL(); 12-20 20:58:09 jdbc[0]: /**/dbMeta3.getTables(null, "", null, new String[]{"TABLE", "VIEW"}); ... To filter the Java source code, use the ConvertTraceFile tool as follows: java -cp h2*.jar org.h2.tools.ConvertTraceFile -traceFile "~/test.trace.db" -javaClass "Test"
The generated file Using Other Logging APIsBy default, this database uses its own native 'trace' facility. This facility is called 'trace' and not 'log' within this database to avoid confusion with the transaction log. Trace messages can be written to both file and System.out. In most cases, this is sufficient, however sometimes it is better to use the same facility as the application, for example Log4j. To do that, this database support SLF4J. SLF4J is a simple facade for various logging APIs and allows to plug in the desired implementation at deployment time. SLF4J supports implementations such as Logback, Log4j, Jakarta Commons Logging (JCL), Java logging, x4juli, and Simple Log. To enable SLF4J, set the file trace level to 4 in the database URL: jdbc:h2:~/test;TRACE_LEVEL_FILE=4 Changing the log mechanism is not possible after the database is open, that means executing the SQL statement SET TRACE_LEVEL_FILE 4 when the database is already open will not have the desired effect. To use SLF4J, all required jar files need to be in the classpath. If it does not work, check the file <database>.trace.db for error messages. Read Only DatabasesIf 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 and CALL 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 whether database is read-only: by calling Connection.isReadOnly() or by executing the SQL statement CALL READONLY(). Read Only Databases in Zip or Jar FileTo create a read-only database in a zip file, first create a regular persistent database, and then create a backup. If you are using a database named 'test', an easy way to do that is using the Backup tool or the BACKUP SQL statement: BACKUP TO 'data.zip' The database must not have pending changes, that means you need to close all connections to the database, open one single connection, and then execute the statement. Afterwards, you can log out, and directly open the database in the zip file using the following database URL: jdbc:h2:zip:~/data.zip!/test Databases in zip files are read-only. The performance for some queries will be slower than when using a regular database, because random access in zip files is not supported (only streaming). How much this affects the performance depends on the queries and the data. The database is not read in memory; therefore large databases are supported as well. The same indexes are used as when using a regular database. Graceful Handling of Low Disk Space SituationsIf the database needs more disk space, it calls the database event listener if one is installed. The application may then delete temporary files, or display a message and wait until the user has resolved the problem. To install a listener, run the SQL statement SET DATABASE_EVENT_LISTENER or use a database 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. Opening a Corrupted DatabaseIf a database cannot 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. Computed Columns / Function Based IndexFunction indexes are not directly supported by this database, but they can be emulated by using computed columns. For example, if an index on the upper-case version of a column is required, create a computed column with the upper-case version of the original column, and create an index for this column: CREATE TABLE ADDRESS( ID INT PRIMARY KEY, NAME VARCHAR, UPPER_NAME VARCHAR AS UPPER(NAME) ); CREATE INDEX IDX_U_NAME ON ADDRESS(UPPER_NAME); When inserting data, it is not required (and 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: INSERT INTO ADDRESS(ID, NAME) VALUES(1, 'Miller'); SELECT * FROM ADDRESS WHERE UPPER_NAME='MILLER'; Multi-Dimensional IndexesA 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. 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). 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. Using PasswordsUsing Secure PasswordsRemember 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: i'sE2rtPiUKtT (it's easy to remember this password if you know the trick) Passwords: Using Char Arrays instead of StringsJava 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). 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. This database supports using char arrays instead of String to pass user and file passwords. The following code can be used to do that: import java.sql.*; import java.util.*; public class Test { public static void main(String[] args) throws Exception { Class.forName("org.h2.Driver"); String url = "jdbc:h2:~/test"; Properties prop = new Properties(); prop.setProperty("user", "sa"); System.out.print("Password?"); char[] password = System.console().readPassword(); prop.put("password", password); Connection conn = null; try { conn = DriverManager.getConnection(url, prop); } finally { Arrays.fill(password, (char) 0); } conn.close(); } } This example requires Java 1.6. When using Swing, use javax.swing.JPasswordField. Passing the User Name and/or Password in the URL
Instead of passing the user name as a separate parameter as in
User-Defined Functions and Stored ProceduresIn 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: package acme; import java.math.*; public class Function { public static boolean isPrime(int value) { return new BigInteger(String.valueOf(value)).isProbablePrime(100); } } The Java function must be registered in the database by calling CREATE ALIAS: CREATE ALIAS IS_PRIME FOR "acme.Function.isPrime" For a complete sample application, see src/test/org/h2/samples/Function.java. Function Data Type MappingFunctions that accept non-nullable parameters such as 'int' will not be called if one of those parameters is NULL. Instead, the result of the function is NULL. If the function should be called if a parameter is NULL, you need to use 'java.lang.Integer' instead of 'int'. SQL types are mapped to Java classes and vice-versa as in the JDBC API. For details, see Data Types. There are two special cases: java.lang.Object is mapped to OTHER (a serialized object). Therefore, java.lang.Object can not be used to match all SQL types (matching all SQL types is not supported). The second special case is Object[]: arrays of any class are mapped to ARRAY. Functions that require a ConnectionIf the first parameter of 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. When calling the method from within the SQL statement, this connection parameter does not need to be (can not be) specified. Functions throwing an ExceptionIf a function throws an Exception, then the current statement is rolled back and the exception is thrown to the application. Functions returning a Result SetFunctions may returns a result set. Such a function can be called with the CALL statement: 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'); Using SimpleResultSetA function can create a result set using the SimpleResultSet tool: 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(); Using a Function as a Table
A function that returns a result set can be used 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 (maybe multiple times 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
public static ResultSet getMatrix(Connection conn, Integer size) throws SQLException { SimpleResultSet rs = new SimpleResultSet(); rs.addColumn("X", Types.INTEGER, 10, 0); rs.addColumn("Y", Types.INTEGER, 10, 0); String url = conn.getMetaData().getURL(); if (url.equals("jdbc:columnlist:connection")) { return rs; } for (int s = size.intValue(), x = 0; x < s; x++) { for (int y = 0; y < s; 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(4) ORDER BY X, Y; TriggersThis 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: import org.h2.api.Trigger; ... public class TriggerSample implements Trigger { public void init(Connection conn, String schemaName, String triggerName, String tableName, boolean before, int type) { public void fire(Connection conn, Object[] oldRow, Object[] newRow) throws SQLException { } } The connection can be used to query or update data in other tables. The trigger then needs to be defined in the database: CREATE TRIGGER INV_INS AFTER INSERT ON INVOICE FOR EACH ROW CALL "org.h2.samples.TriggerSample" The trigger can be used to veto a change, by throwing a SQLException. Compacting a DatabaseEmpty space in the database file is re-used automatically. To re-build the indexes, the simplest 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: 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); } See also the sample application org.h2.samples.Compact. The commands SCRIPT / RUNSCRIPT can be used as well to create a backup of a database and re-build the database from the script. Cache SettingsThe 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. This database supports two cache page replacement algorithms: LRU (the default) and TQ. For LRU, the pages that were least frequently used are removed from the cache if it becomes full. The TQ (Two Queue, also called 2Q) algorithm is a bit more complicated: basically two queues are used. It is more resistant to table scans, however the overhead is a bit higher compared to the LRU. To use the cache algorithm TQ, use a database URL of the form jdbc:h2:~/test;CACHE_TYPE=TQ. The cache algorithm cannot be changed once the database is open. Also supported is a second level soft reference cache. Rows in this cache are only garbage collected on low memory. By default the second level cache is disabled. To enable it, use the prefix SOFT_. Example: jdbc:h2:~/test;CACHE_TYPE=SOFT_LRU . 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. |