TutorialStarting and Using the H2 ConsoleSpecial H2 Console Syntax Settings of the H2 Console Connecting to a Database using JDBC Creating New Databases Using the Server Using Hibernate Using TopLink and Glassfish Using EclipseLink Using Apache ActiveMQ Using H2 within NetBeans Using H2 with jOOQ Using Databases in Web Applications Android CSV (Comma Separated Values) Support Upgrade, Backup, and Restore Command Line Tools The Shell Tool Using OpenOffice Base Java Web Start / JNLP Using a Connection Pool Fulltext Search User-Defined Variables Date and Time Using Spring OSGi Java Management Extension (JMX) Starting and Using the H2 ConsoleThe H2 Console application lets you access a database using a browser. This can be a H2 database, or another database that supports the JDBC API. ![]() This is a client/server application, so both a server and a client (a browser) are required to run it. Depending on your platform and environment, there are multiple ways to start the H2 Console:
FirewallIf you start the server, you may get a security warning from the firewall (if you have installed one). If you don't want other computers in the network to access the application on your machine, you can let the firewall block those connections. The connection from the local machine will still work. Only if you want other computers to access the database on this computer, you need allow remote connections in the firewall. It has been reported that when using Kaspersky 7.0 with firewall, the H2 Console is very slow when connecting over the IP address. A workaround is to connect using 'localhost'. A small firewall is already built into the server: other computers may not connect to the server by default. To change this, go to 'Preferences' and select 'Allow connections from other computers'. Testing JavaTo find out which version of Java is installed, open a command prompt and type: java -version If you get an error message, you may need to add the Java binary directory to the path environment variable. Error Message 'Port may be in use'You can only start one instance of the H2 Console, otherwise you will get the following error message: "The Web server could not be started. Possible cause: another server is already running...". It is possible to start multiple console applications on the same computer (using different ports), but this is usually not required as the console supports multiple concurrent connections. Using another Port
If the default port of the H2 Console is already in use by another application,
then a different port needs to be configured. The settings are stored in a properties file.
For details, see Settings of the H2 Console.
The relevant entry is If no port is specified for the TCP and PG servers, each service will try to listen on its default port. If the default port is already in use, a random port is used. Connecting to the Server using a Browser
If the server started successfully, you can connect to it using a web browser.
Javascript needs to be enabled.
If you started the server on the same computer as the browser, open the URL Multiple Concurrent SessionsMultiple concurrent browser sessions are supported. As that the database objects reside on the server, the amount of concurrent work is limited by the memory available to the server application. LoginAt the login page, you need to provide connection information to connect to a database. Set the JDBC driver class of your database, the JDBC URL, user name, and password. If you are done, click [Connect]. You can save and reuse previously saved settings. The settings are stored in a properties file (see Settings of the H2 Console). Error MessagesError messages in are shown in red. You can show/hide the stack trace of the exception by clicking on the message. Adding Database Drivers
To register additional JDBC drivers (MySQL, PostgreSQL, HSQLDB,...),
add the jar file names to the environment variables
Multiple drivers can be set; entries need to be separated by Using the H2 ConsoleThe H2 Console application has three main panels: the toolbar on top, the tree on the left, and the query/result panel on the right. The database objects (for example, tables) are listed on the left. Type a SQL command in the query panel and click [Run]. The result appears just below the command. Inserting Table Names or Column Names
To insert table and column names into the script, click on the item in the tree.
If you click on a table while the query is empty, then Disconnecting and Stopping the ApplicationTo log out of the database, click [Disconnect] in the toolbar panel. However, the server is still running and ready to accept new sessions. To stop the server, right click on the system tray icon and select [Exit]. If you don't have the system tray icon, navigate to [Preferences] and click [Shutdown], press [Ctrl]+[C] in the console where the server was started (Windows), or close the console window. Special H2 Console Syntax
The H2 Console supports a few built-in commands.
Those are interpreted within the H2 Console, so they work with any database.
Built-in commands need to be at the beginning of a statement (before any remarks),
otherwise they are not parsed correctly. If in doubt, add
Settings of the H2 Console
The settings of the H2 Console are stored in a configuration file
called
In addition to those settings, the properties of the last recently used connection
are listed in the form
Connecting to a Database using JDBCTo connect to a database, a Java application first needs to load the database driver, and then get a connection. A simple way to do that is using the following code: import java.sql.*; public class Test { public static void main(String[] a) throws Exception { Connection conn = DriverManager. getConnection("jdbc:h2:~/test", "sa", ""); // add application code here conn.close(); } }
This code opens a connection (using Creating New DatabasesBy default, if the database specified in the URL does not yet exist, a new (empty) database is created automatically. The user that created the database automatically becomes the administrator of this database. Auto-creating new database can be disabled, see Opening a Database Only if it Already Exists. Using the Server
H2 currently supports three server: a web server (for the H2 Console),
a TCP server (for client/server connections) and an PG server (for PostgreSQL clients).
Please note that only the web server supports browser connections.
The servers can be started in different ways, one is using the Starting the Server Tool from Command Line
To start the java -cp h2*.jar org.h2.tools.Server This will start the tool with the default options. To get the list of options and default values, run: java -cp h2*.jar org.h2.tools.Server -? There are options available to use other ports, and start or not start parts. Connecting to the TCP ServerTo remotely connect to a database using the TCP server, use the following driver and database URL:
For details about the database URL, see also in Features. Please note that you can't connection with a web browser to this URL. You can only connect using a H2 client (over JDBC). Starting the TCP Server within an ApplicationServers can also be started and stopped from within an application. Sample code: import org.h2.tools.Server; ... // start the TCP Server Server server = Server.createTcpServer(args).start(); ... // stop the TCP Server server.stop(); Stopping a TCP Server from Another ProcessThe TCP server can be stopped from another process. To stop the server from the command line, run: java org.h2.tools.Server -tcpShutdown tcp://localhost:9092 To stop the server from a user application, use the following code: org.h2.tools.Server.shutdownTcpServer("tcp://localhost:9094");
This function will only stop the TCP server.
If other server were started in the same process, they will continue to run.
To avoid recovery when the databases are opened the next time,
all connections to the databases should be closed before calling this method.
To stop a remote server, remote connections must be enabled on the server.
Shutting down a TCP server can be protected using the option Using HibernateThis database supports Hibernate version 3.1 and newer. You can use the HSQLDB Dialect, or the native H2 Dialect.
When using Hibernate, try to use the Using TopLink and Glassfish
To use H2 with Glassfish (or Sun AS), set the Datasource Classname to
The H2 database is compatible with HSQLDB and PostgreSQL.
To take advantage of H2 specific features, use the <property name="toplink.target-database" value="oracle.toplink.essentials.platform.database.H2Platform"/>
In old versions of Glassfish, the property name is
To use H2 within Glassfish, copy the h2*.jar to the directory Using EclipseLink
To use H2 in EclipseLink, use the platform class Using Apache ActiveMQ
When using H2 as the backend database for Apache ActiveMQ, please use the Using H2 within NetBeans
There is a known issue when using the Netbeans SQL Execution Window:
before executing a query, another query in the form Using H2 with jOOQjOOQ adds a thin layer on top of JDBC, allowing for type-safe SQL construction, including advanced SQL, stored procedures and advanced data types. jOOQ takes your database schema as a base for code generation. If this is your example schema: CREATE TABLE USER (ID INT, NAME VARCHAR(50)); then run the jOOQ code generator on the command line using this command: java -cp jooq.jar;jooq-meta.jar;jooq-codegen.jar;h2-1.3.158.jar;. org.jooq.util.GenerationTool /codegen.xml
...where <?xml version="1.0" encoding="UTF-8" standalone="yes"?> <configuration xmlns="http://www.jooq.org/xsd/jooq-codegen-2.3.0.xsd"> <jdbc> <driver>org.h2.Driver</driver> <url>jdbc:h2:~/test</url> <user>sa</user> <password></password> </jdbc> <generator> <name>org.jooq.util.DefaultGenerator</name> <database> <name>org.jooq.util.h2.H2Database</name> <includes>.*</includes> <excludes></excludes> <inputSchema>PUBLIC</inputSchema> </database> <generate></generate> <target> <packageName>org.jooq.h2.generated</packageName> <directory>./src</directory> </target> </generator> </configuration> Using the generated source, you can query the database as follows: Factory create = new H2Factory(connection); Result<UserRecord> result = create.selectFrom(USER) .where(NAME.like("Johnny%")) .orderBy(ID) .fetch(); See more details on jOOQ Homepage and in the jOOQ Tutorial Using Databases in Web ApplicationsThere are multiple ways to access a database from within web applications. Here are some examples if you use Tomcat or JBoss. Embedded Mode
The (currently) simplest solution is to use the database in the
embedded mode, that means open a connection in your application when
it starts (a good solution is using a Servlet Listener, see below), or
when a session starts. A database can be accessed from multiple
sessions and applications at the same time, as long as they run in the
same process. Most Servlet Containers (for example Tomcat) are just
using one process, so this is not a problem (unless you run Tomcat in
clustered mode). Tomcat uses multiple threads and multiple
classloaders. If multiple applications access the same database at the
same time, you need to put the database jar in the Server ModeThe server mode is similar, but it allows you to run the server in another process. Using a Servlet Listener to Start and Stop a Database
Add the h2*.jar file to your web application, and
add the following snippet to your web.xml file (between the
<listener> <listener-class>org.h2.server.web.DbStarter</listener-class> </listener>
For details on how to access the database, see the file Connection conn = getServletContext().getAttribute("connection");
<context-param> <param-name>db.url</param-name> <param-value>jdbc:h2:~/test</param-value> </context-param> <context-param> <param-name>db.user</param-name> <param-value>sa</param-value> </context-param> <context-param> <param-name>db.password</param-name> <param-value>sa</param-value> </context-param> <context-param> <param-name>db.tcpServer</param-name> <param-value>-tcpAllowOthers</param-value> </context-param>
When the web application is stopped, the database connection will be closed automatically.
If the TCP server is started within the Using the H2 Console Servlet
The H2 Console is a standalone application and includes its own web server, but it can be
used as a servlet as well. To do that, include the the <servlet> <servlet-name>H2Console</servlet-name> <servlet-class>org.h2.server.web.WebServlet</servlet-class> <!-- <init-param> <param-name>webAllowOthers</param-name> <param-value></param-value> </init-param> <init-param> <param-name>trace</param-name> <param-value></param-value> </init-param> --> <load-on-startup>1</load-on-startup> </servlet> <servlet-mapping> <servlet-name>H2Console</servlet-name> <url-pattern>/console/*</url-pattern> </servlet-mapping>
For details, see also To create a web application with just the H2 Console, run the following command: build warConsole AndroidYou can use this database on an Android device (using the Dalvik VM) instead of or in addition to SQLite. So far, only very few tests and benchmarks were run, but it seems that performance is similar to SQLite, except for opening and closing a database, which is not yet optimized in H2 (H2 takes about 0.2 seconds, and SQLite about 0.02 seconds). Read operations seem to be a bit faster than SQLite, and write operations seem to be slower. So far, only very few tests have been run, and everything seems to work as expected. Fulltext search was not yet tested, however the native fulltext search should work. Reasons to use H2 instead of SQLite are:
Currently only the JDBC API is supported (it is planned to support the Android database API in future releases).
Both the regular H2 jar file and the smaller The database files needs to be stored in a place that is accessible for the application. Example: String url = "jdbc:h2:/data/data/" + "com.example.hello" + "/data/hello" + ";FILE_LOCK=FS" + ";PAGE_SIZE=1024" + ";CACHE_SIZE=8192"; conn = DriverManager.getConnection(url); ...
Limitations: Using a connection pool is currently not supported, because the required CSV (Comma Separated Values) Support
The CSV file support can be used inside the database using the functions
Reading a CSV File from Within a Database
A CSV file can be read using the function SELECT * FROM CSVREAD('test.csv');
Please note for performance reason, Importing Data from a CSV File
A fast way to load or import data (sometimes called 'bulk load') from a CSV file is
to combine table creation with import.
Optionally, the column names and data types can be set when creating the table.
Another option is to use CREATE TABLE TEST AS SELECT * FROM CSVREAD('test.csv'); CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255)) AS SELECT * FROM CSVREAD('test.csv'); Writing a CSV File from Within a Database
The built-in function CREATE TABLE TEST(ID INT, NAME VARCHAR); INSERT INTO TEST VALUES(1, 'Hello'), (2, 'World'); CALL CSVWRITE('test.csv', 'SELECT * FROM TEST'); Writing a CSV File from a Java Application
The import java.sql.*; import org.h2.tools.Csv; import org.h2.tools.SimpleResultSet; public class TestCsv { public static void main(String[] args) throws Exception { SimpleResultSet rs = new SimpleResultSet(); rs.addColumn("NAME", Types.VARCHAR, 255, 0); rs.addColumn("EMAIL", Types.VARCHAR, 255, 0); rs.addRow("Bob Meier", "bob.meier@abcde.abc"); rs.addRow("John Jones", "john.jones@abcde.abc"); new Csv().write("data/test.csv", rs, null); } } Reading a CSV File from a Java ApplicationIt is possible to read a CSV file without opening a database. Example: import java.sql.*; import org.h2.tools.Csv; public class TestCsv { public static void main(String[] args) throws Exception { ResultSet rs = new Csv().read("data/test.csv", null, null); ResultSetMetaData meta = rs.getMetaData(); while (rs.next()) { for (int i = 0; i < meta.getColumnCount(); i++) { System.out.println( meta.getColumnLabel(i + 1) + ": " + rs.getString(i + 1)); } System.out.println(); } rs.close(); } } Upgrade, Backup, and RestoreDatabase UpgradeThe recommended way to upgrade from one version of the database engine to the next version is to create a backup of the database (in the form of a SQL script) using the old engine, and then execute the SQL script using the new engine. Backup using the Script Tool
The recommended way to backup a database is to create a compressed SQL script file.
This will result in a small, human readable, and database version independent backup.
Creating the script will also verify the checksums of the database file.
The java org.h2.tools.Script -url jdbc:h2:~/test -user sa -script test.zip -options compression zip
It is also possible to use the SQL command Restore from a Script
To restore a database from a SQL script file, you can use the java org.h2.tools.RunScript -url jdbc:h2:~/test -user sa -script test.zip -options compression zip
For more information about the options, see the SQL command Online Backup
The The resulting backup is transactionally consistent, meaning the consistency and atomicity rules apply. BACKUP TO 'backup.zip'
The Creating a backup by copying the database files while the database is running is not supported, except if the file systems support creating snapshots. With other file systems, it can't be guaranteed that the data is copied in the right order. Command Line ToolsThis database comes with a number of command line tools. To get more information about a tool, start it with the parameter '-?', for example: java -cp h2*.jar org.h2.tools.Backup -? The command line tools are:
The tools can also be called from an application by calling the main or another public method. For details, see the Javadoc documentation. The Shell ToolThe Shell tool is a simple interactive command line tool. To start it, type: java -cp h2*.jar org.h2.tools.Shell
You will be asked for a database URL, JDBC driver, user name, and password.
The connection setting can also be set as command line parameters.
After connecting, you will get the list of options.
The built-in commands don't need to end with a semicolon, but
SQL statements are only executed if the line ends with a semicolon sql> select * from test ...> where id = 0; By default, results are printed as a table. For results with many column, consider using the list mode: sql> list Result list mode is now on sql> select * from test; ID : 1 NAME: Hello ID : 2 NAME: World (2 rows, 0 ms) Using OpenOffice BaseOpenOffice.org Base supports database access over the JDBC API. To connect to a H2 database using OpenOffice Base, you first need to add the JDBC driver to OpenOffice. The steps to connect to a H2 database are:
Now you can access the database stored in the current users home directory. To use H2 in NeoOffice (OpenOffice without X11):
Now, when creating a new database using the "Database Wizard" :
Another solution to use H2 in NeoOffice is:
This can be done by create it using the NetBeans OpenOffice plugin. See also Extensions Development. Java Web Start / JNLP
When using Java Web Start / JNLP (Java Network Launch Protocol), permissions tags must be set in the .jnlp file,
and the application .jar file must be signed. Otherwise, when trying to write to the file system, the following
exception will occur: <security> <all-permissions/> </security> Using a Connection Pool
For H2, opening a connection is fast if the database is already open.
Still, using a connection pool improves performance if you open and close connections a lot.
A simple connection pool is included in H2. It is based on the
Mini Connection Pool Manager
from Christian d'Heureuse. There are other, more complex, open source connection pools available,
for example the Apache Commons DBCP.
For H2, it is about twice as faster to get a connection from the built-in connection pool than to get
one using import java.sql.*; import org.h2.jdbcx.JdbcConnectionPool; public class Test { public static void main(String[] args) throws Exception { JdbcConnectionPool cp = JdbcConnectionPool.create( "jdbc:h2:~/test", "sa", "sa"); for (int i = 0; i < args.length; i++) { Connection conn = cp.getConnection(); conn.createStatement().execute(args[i]); conn.close(); } cp.dispose(); } } Fulltext SearchH2 includes two fulltext search implementations. One is using Apache Lucene, and the other (the native implementation) stores the index data in special tables in the database. Using the Native Fulltext SearchTo initialize, call: CREATE ALIAS IF NOT EXISTS FT_INIT FOR "org.h2.fulltext.FullText.init"; CALL FT_INIT(); You need to initialize it in each database where you want to use it. Afterwards, you can create a fulltext index for a table using: CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR); INSERT INTO TEST VALUES(1, 'Hello World'); CALL FT_CREATE_INDEX('PUBLIC', 'TEST', NULL); PUBLIC is the schema name, TEST is the table name. The list of column names (comma separated) is optional, in this case all columns are indexed. The index is updated in realtime. To search the index, use the following query: SELECT * FROM FT_SEARCH('Hello', 0, 0); This will produce a result set that contains the query needed to retrieve the data: QUERY: "PUBLIC"."TEST" WHERE "ID"=1 To drop an index on a table: CALL FT_DROP_INDEX('PUBLIC', 'TEST');
To get the raw data, use You can also call the index from within a Java application: org.h2.fulltext.FullText.search(conn, text, limit, offset); org.h2.fulltext.FullText.searchData(conn, text, limit, offset); Using the Apache Lucene Fulltext Search
To use the Apache Lucene full text search, you need the Lucene library in the classpath.
Currently, Apache Lucene 3.6.2 is used for testing.
Newer versions may work, however they are not tested.
How to do that depends on the application; if you use the H2 Console, you can add the Lucene
jar file to the environment variables CREATE ALIAS IF NOT EXISTS FTL_INIT FOR "org.h2.fulltext.FullTextLucene.init"; CALL FTL_INIT(); You need to initialize it in each database where you want to use it. Afterwards, you can create a full text index for a table using: CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR); INSERT INTO TEST VALUES(1, 'Hello World'); CALL FTL_CREATE_INDEX('PUBLIC', 'TEST', NULL); PUBLIC is the schema name, TEST is the table name. The list of column names (comma separated) is optional, in this case all columns are indexed. The index is updated in realtime. To search the index, use the following query: SELECT * FROM FTL_SEARCH('Hello', 0, 0); This will produce a result set that contains the query needed to retrieve the data: QUERY: "PUBLIC"."TEST" WHERE "ID"=1 To drop an index on a table (be warned that this will re-index all of the full-text indices for the entire database): CALL FTL_DROP_INDEX('PUBLIC', 'TEST');
To get the raw data, use You can also call the index from within a Java application: org.h2.fulltext.FullTextLucene.search(conn, text, limit, offset); org.h2.fulltext.FullTextLucene.searchData(conn, text, limit, offset); The Lucene fulltext search supports searching in specific column only. Column names must be uppercase (except if the original columns are double quoted). For column names starting with an underscore (_), another underscore needs to be added. Example: CREATE ALIAS IF NOT EXISTS FTL_INIT FOR "org.h2.fulltext.FullTextLucene.init"; CALL FTL_INIT(); DROP TABLE IF EXISTS TEST; CREATE TABLE TEST(ID INT PRIMARY KEY, FIRST_NAME VARCHAR, LAST_NAME VARCHAR); CALL FTL_CREATE_INDEX('PUBLIC', 'TEST', NULL); INSERT INTO TEST VALUES(1, 'John', 'Wayne'); INSERT INTO TEST VALUES(2, 'Elton', 'John'); SELECT * FROM FTL_SEARCH_DATA('John', 0, 0); SELECT * FROM FTL_SEARCH_DATA('LAST_NAME:John', 0, 0); CALL FTL_DROP_ALL(); User-Defined Variables
This database supports user-defined variables. Variables start with SET @USER = 'Joe'; The value can also be changed using the SET() method. This is useful in queries: SET @TOTAL = NULL; SELECT X, SET(@TOTAL, IFNULL(@TOTAL, 1.) * X) F FROM SYSTEM_RANGE(1, 50);
Variables that are not set evaluate to Date and TimeDate, time and timestamp values support ISO 8601 formatting, including time zone: CALL TIMESTAMP '2008-01-01 12:00:00+01:00'; If the time zone is not set, the value is parsed using the current time zone setting of the system. Date and time information is stored in H2 database files with or without time zone information depending on used data type.
Using SpringUsing the TCP ServerUse the following configuration to start and stop the H2 TCP server using the Spring Framework: <bean id = "org.h2.tools.Server" class="org.h2.tools.Server" factory-method="createTcpServer" init-method="start" destroy-method="stop"> <constructor-arg value="-tcp,-tcpAllowOthers,-tcpPort,8043" /> </bean>
The OSGi
The standard H2 jar can be dropped in as a bundle in an OSGi container.
H2 implements the JDBC Service defined in OSGi Service Platform Release 4 Version 4.2 Enterprise Specification.
The H2 Data Source Factory service is registered with the following properties:
The following standard configuration properties are supported:
Java Management Extension (JMX)
Management over JMX is supported, but not enabled by default.
To enable JMX, append The following attributes and operations are supported:
To enable JMX, you may need to set the system properties |