advanced.html 66.0 KB
Newer Older
1 2
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Strict//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd">
<!--
3
Copyright 2004-2010 H2 Group. Multiple-Licensed under the H2 License, Version 1.0,
4 5 6 7 8 9
and under the Eclipse Public 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>
10
Advanced
11 12 13 14 15 16 17
</title><link rel="stylesheet" type="text/css" href="stylesheet.css" />
<!-- [search] { -->
<script type="text/javascript" src="navigation.js"></script>
</head><body onload="frameMe();">
<table class="content"><tr class="content"><td class="content"><div class="contentDiv">
<!-- } -->

18
<h1>Advanced</h1>
19 20 21 22 23 24
<a href="#result_sets">
    Result Sets</a><br />
<a href="#large_objects">
    Large Objects</a><br />
<a href="#linked_tables">
    Linked Tables</a><br />
Thomas Mueller's avatar
Thomas Mueller committed
25 26
<a href="#recursive_queries">
    Recursive Queries</a><br />
27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52
<a href="#transaction_isolation">
    Transaction Isolation</a><br />
<a href="#mvcc">
    Multi-Version Concurrency Control (MVCC)</a><br />
<a href="#clustering">
    Clustering / High Availability</a><br />
<a href="#two_phase_commit">
    Two Phase Commit</a><br />
<a href="#compatibility">
    Compatibility</a><br />
<a href="#standards_compliance">
    Standards Compliance</a><br />
<a href="#windows_service">
    Run as Windows Service</a><br />
<a href="#odbc_driver">
    ODBC Driver</a><br />
<a href="#microsoft_dot_net">
    Using H2 in Microsoft .NET</a><br />
<a href="#acid">
    ACID</a><br />
<a href="#durability_problems">
    Durability Problems</a><br />
<a href="#using_recover_tool">
    Using the Recover Tool</a><br />
<a href="#file_locking_protocols">
    File Locking Protocols</a><br />
53 54
<a href="#file_locking_serialized">
    File Locking Method 'Serialized'</a><br />
55 56
<a href="#sql_injection">
    Protection against SQL Injection</a><br />
57 58
<a href="#remote_access">
    Protection against Remote Access</a><br />
59 60 61 62 63 64 65 66 67 68 69 70
<a href="#restricting_classes">
    Restricting Class Loading and Usage</a><br />
<a href="#security_protocols">
    Security Protocols</a><br />
<a href="#ssl_tls_connections">
    SSL/TLS Connections</a><br />
<a href="#uuid">
    Universally Unique Identifiers (UUID)</a><br />
<a href="#system_properties">
    Settings Read from System Properties</a><br />
<a href="#server_bind_address">
    Setting the Server Bind Address</a><br />
71 72
<a href="#file_system">
    Pluggable File System</a><br />
73 74
<a href="#database_upgrade">
    Database Upgrade</a><br />
Thomas Mueller's avatar
Thomas Mueller committed
75 76
<a href="#limits_limitations">
    Limits and Limitations</a><br />
77 78 79
<a href="#glossary_links">
    Glossary and Links</a><br />

Thomas Mueller's avatar
Thomas Mueller committed
80
<h2 id="result_sets">Result Sets</h2>
81

82 83
<h3>Statements that Return a Result Set</h3>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
84
The following statements return a result set: <code>SELECT, EXPLAIN, CALL, SCRIPT, SHOW, HELP</code>.
85 86 87
All other statements return an update count.
</p>

88 89 90 91 92 93
<h3>Limiting the Number of Rows</h3>
<p>
Before the result is returned to the application, all rows are read by the database.
Server side cursors are not supported currently.
If only the first few rows are interesting for the application, then the
result set size should be limited to improve the performance.
94 95 96
This can be done using <code>LIMIT</code> in a query
(example: <code>SELECT * FROM TEST LIMIT 100</code>),
or by using <code>Statement.setMaxRows(max)</code>.
97 98 99 100
</p>

<h3>Large Result Sets and External Sorting</h3>
<p>
101
For large result set, the result is buffered to disk. The threshold can be defined using the statement
102 103
<code>SET MAX_MEMORY_ROWS</code>.
If <code>ORDER BY</code> is used, the sorting is done using an
104 105 106
external sort algorithm.
In this case, each block of rows is sorted using quick sort, then written to disk;
when reading the data, the blocks are merged together.
107 108
</p>

Thomas Mueller's avatar
Thomas Mueller committed
109
<h2 id="large_objects">Large Objects</h2>
110 111 112 113 114 115

<h3>Storing and Reading Large Objects</h3>
<p>
If it is possible that the objects don't fit into memory, then the data type
CLOB (for textual data) or BLOB (for binary data) should be used.
For these data types, the objects are not fully read into memory, by using streams.
116 117 118
To store a BLOB, use <code>PreparedStatement.setBinaryStream</code>. To store a CLOB, use
<code>PreparedStatement.setCharacterStream</code>. To read a BLOB, use <code>ResultSet.getBinaryStream</code>,
and to read a CLOB, use <code>ResultSet.getCharacterStream</code>.
119 120
When using the client/server mode, large BLOB and CLOB data is stored in a temporary file
on the client side.
121 122
</p>

123 124 125 126
<h3>When to use CLOB/BLOB</h3>
<p>
This database stores large LOB (CLOB and BLOB) objects as separate files.
Small LOB objects are stored in-place, the threshold can be set using
127
<a href="grammar.html#set_max_length_inplace_lob" class="notranslate" >MAX_LENGTH_INPLACE_LOB</a>,
128 129 130 131 132 133 134 135 136
but there is still an overhead to use CLOB/BLOB. Because of this, BLOB and CLOB
should never be used for columns with a maximum size below about 200 bytes.
The best threshold depends on the use case; reading in-place objects is faster
than reading from separate files, but slows down the performance of operations
that don't involve this column.
</p>

<h3>Large Object Compression</h3>
<p>
137 138
CLOB and BLOB values can be compressed by using
<a href="grammar.html#set_compress_lob" class="notranslate" >SET COMPRESS_LOB</a>.
139 140 141 142 143
The LZF algorithm is faster but needs more disk space. By default compression is disabled, which usually speeds up write
operations. If you store many large compressible values such as XML, HTML, text, and uncompressed binary files,
then compressing can save a lot of disk space (sometimes more than 50%), and read operations may even be faster.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
144
<h2 id="linked_tables">Linked Tables</h2>
145 146
<p>
This database supports linked tables, which means tables that don't exist in the current database but
147
are just links to another database. To create such a link, use the
148
<code>CREATE LINKED TABLE</code> statement:
149
</p>
150
<pre>
151 152 153 154 155
CREATE LINKED TABLE LINK('org.postgresql.Driver', 'jdbc:postgresql:test', 'sa', 'sa', 'TEST');
</pre>
<p>
You can then access the table in the usual way.
Whenever the linked table is accessed, the database issues specific queries over JDBC.
156 157
Using the example above, if you issue the query <code>SELECT * FROM LINK WHERE ID=1</code>,
then the following query is run against the PostgreSQL database: <code>SELECT * FROM TEST WHERE ID=?</code>.
158 159 160 161 162 163 164 165
The same happens for insert and update statements. Only simple statements are executed against the
target database, that means no joins. Prepared statements are used where possible.
</p>
<p>
To view the statements that are executed against the target table, set the trace level to 3.
</p>
<p>
If multiple linked tables point to the same database (using the same database URL), the connection
166
is shared. To disable this, set the system property <code>h2.shareLinkedConnections=false</code>.
167 168
</p>
<p>
169 170
The statement <a href="grammar.html#create_linked_table" class="notranslate" >CREATE LINKED TABLE</a>
supports an optional schema name parameter.
171 172
</p>

Thomas Mueller's avatar
Thomas Mueller committed
173
<h2 id="transaction_isolation">Transaction Isolation</h2>
174 175 176
<p>
Transaction isolation is provided for all data manipulation language (DML) statements.
Most data definition language (DDL) statements commit the current transaction.
177
See the <a href="grammar.html">Grammar</a> for details.
178
</p>
179 180 181 182 183 184
<p>
This database supports the following transaction isolation levels:
</p>
<ul>
<li><b>Read Committed</b><br />
    This is the default level.
Thomas Mueller's avatar
Thomas Mueller committed
185
    Read locks are released immediately after executing the statement, but write locks are kept until the transaction commits.
186
    Higher concurrency is possible when using this level.<br />
187 188
    To enable, execute the SQL statement <code>SET LOCK_MODE 3</code><br />
    or append <code>;LOCK_MODE=3</code> to the database URL: <code>jdbc:h2:~/test;LOCK_MODE=3</code>
189 190
</li><li>
<b>Serializable</b><br />
Thomas Mueller's avatar
Thomas Mueller committed
191
    Both read locks and write locks are kept until the transaction commits.
192 193
    To enable, execute the SQL statement <code>SET LOCK_MODE 1</code><br />
    or append <code>;LOCK_MODE=1</code> to the database URL: <code>jdbc:h2:~/test;LOCK_MODE=1</code>
194 195
</li><li><b>Read Uncommitted</b><br />
    This level means that transaction isolation is disabled.<br />
196 197
    To enable, execute the SQL statement <code>SET LOCK_MODE 0</code><br />
    or append <code>;LOCK_MODE=0</code> to the database URL: <code>jdbc:h2:~/test;LOCK_MODE=0</code>
198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232
</li>
</ul>
<p>
When using the isolation level 'serializable', dirty reads, non-repeatable reads, and phantom reads are prohibited.
</p>
<ul>
<li><b>Dirty Reads</b><br />
    Means a connection can read uncommitted changes made by another connection.<br />
    Possible with: read uncommitted
</li><li><b>Non-Repeatable Reads</b><br />
    A connection reads a row, another connection changes a row and commits,
    and the first connection re-reads the same row and gets the new result.<br />
    Possible with: read uncommitted, read committed
</li><li><b>Phantom Reads</b><br />
    A connection reads a set of rows using a condition, another connection
    inserts a row that falls in this condition and commits, then the first connection
    re-reads using the same condition and gets the new row.<br />
    Possible with: read uncommitted, read committed
</li>
</ul>

<h3>Table Level Locking</h3>
<p>
The database allows multiple concurrent connections to the same database.
To make sure all connections only see consistent data, table level locking is used by default.
This mechanism does not allow high concurrency, but is very fast.
Shared locks and exclusive locks are supported.
Before reading from a table, the database tries to add a shared lock to the table
(this is only possible if there is no exclusive lock on the object by another connection).
If the shared lock is added successfully, the table can be read. It is allowed that
other connections also have a shared lock on the same object. If a connection wants
to write to a table (update or delete a row), an exclusive lock is required. To get the
exclusive lock, other connection must not have any locks on the object. After the
connection commits, all locks are released.
This database keeps all locks in memory.
Thomas Mueller's avatar
Thomas Mueller committed
233
When a lock is released, and multiple connections are waiting for it, one of them is picked at random.
234 235 236 237 238 239 240 241 242 243 244 245
</p>

<h3>Lock Timeout</h3>
<p>
If a connection cannot get a lock on an object, the connection waits for some amount
of time (the lock timeout). During this time, hopefully the connection holding the
lock commits and it is then possible to get the lock. If this is not possible because
the other connection does not release the lock for some time, the unsuccessful
connection will get a lock timeout exception. The lock timeout can be set individually
for each connection.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
246
<h2 id="mvcc">Multi-Version Concurrency Control (MVCC)</h2>
247 248 249 250
<p>
The MVCC feature allows higher concurrency than using (table level or row level) locks.
When using MVCC in this database, delete, insert and update operations will only issue a
shared lock on the table. An exclusive lock is still used when adding or removing columns,
251
when dropping the table, and when using <code>SELECT ... FOR UPDATE</code>.
252
Connections only 'see' committed data, and own changes. That means, if connection A updates
253 254
a row but doesn't commit this change yet, connection B will see the old value.
Only when the change is committed, the new value is visible by other connections
255 256
(read committed). If multiple connections concurrently try to update the same row, the
database waits until it can apply the change, but at most until the lock timeout expires.
257 258
</p>
<p>
259
To use the MVCC feature, append <code>;MVCC=TRUE</code> to the database URL:
260
</p>
261
<pre>
262 263 264
jdbc:h2:~/test;MVCC=TRUE
</pre>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
265
MVCC is disabled by default. The MVCC feature is not fully tested yet.
266
The limitations of the MVCC mode are: it can not be used at the same time as
267
<code>MULTI_THREADED=TRUE</code>;
268
the complete undo log must fit in memory when using multi-version concurrency
269
(the setting <code>MAX_MEMORY_UNDO</code> has no effect).
Thomas Mueller's avatar
Thomas Mueller committed
270 271
It is not possible to enable or disable this setting while the database is already open.
The setting must be specified in the first connection (the one that opens the database).
272 273
</p>

Thomas Mueller's avatar
Thomas Mueller committed
274
<h2 id="clustering">Clustering / High Availability</h2>
275 276 277 278 279 280 281 282 283
<p>
This database supports a simple clustering / high availability mechanism. The architecture is:
two database servers run on two different computers, and on both computers is a copy of the
same database. If both servers run, each database operation is executed on both computers.
If one server fails (power, hardware or network failure), the other server can still continue to work.
From this point on, the operations will be executed only on one server until the other server
is back up.
</p><p>
Clustering can only be used in the server mode (the embedded mode does not support clustering).
Thomas Mueller's avatar
Thomas Mueller committed
284 285 286
The cluster can be re-created using the <code>CreateCluster</code> tool without stopping
the remaining server. Applications that are still connected are automatically disconnected,
however when appending <code>;AUTO_RECONNECT=TRUE</code>, they will recover from that.
287 288 289 290 291
</p><p>
To initialize the cluster, use the following steps:
</p>
<ul>
<li>Create a database
292
</li><li>Use the <code>CreateCluster</code> tool to copy the database to
293
    another location and initialize the clustering.
294 295 296 297 298 299 300 301 302 303 304 305
    Afterwards, you have two databases containing the same data.
</li><li>Start two servers (one for each copy of the database)
</li><li>You are now ready to connect to the databases with the client application(s)
</li></ul>

<h3>Using the CreateCluster Tool</h3>
<p>
To understand how clustering works, please try out the following example.
In this example, the two databases reside on the same computer, but usually, the
databases will be on different servers.
</p>
<ul>
306
<li>Create two directories: <code>server1, server2</code>.
307 308 309
    Each directory will simulate a directory on a computer.
</li><li>Start a TCP server pointing to the first directory.
    You can do this using the command line:
310
<pre>
311 312 313 314 315 316 317
java org.h2.tools.Server
    -tcp -tcpPort 9101
    -baseDir server1
</pre>
</li><li>Start a second TCP server pointing to the second directory.
    This will simulate a server running on a second (redundant) computer.
    You can do this using the command line:
318
<pre>
319 320 321 322
java org.h2.tools.Server
    -tcp -tcpPort 9102
    -baseDir server2
</pre>
323
</li><li>Use the <code>CreateCluster</code> tool to initialize clustering.
324 325
    This will automatically create a new, empty database if it does not exist.
    Run the tool on the command line:
326
<pre>
327
java org.h2.tools.CreateCluster
Thomas Mueller's avatar
Thomas Mueller committed
328 329 330 331
    -urlSource jdbc:h2:tcp://localhost:9101/~/test
    -urlTarget jdbc:h2:tcp://localhost:9102/~/test
    -user sa
    -serverList localhost:9101,localhost:9102
332 333 334
</pre>
</li><li>You can now connect to the databases using
an application or the H2 Console using the JDBC URL
335
<code>jdbc:h2:tcp://localhost:9101,localhost:9102/~/test</code>
336 337 338 339 340
</li><li>If you stop a server (by killing the process),
you will notice that the other machine continues to work,
and therefore the database is still accessible.
</li><li>To restore the cluster, you first need to delete the
database that failed, then restart the server that was stopped,
341
and re-run the <code>CreateCluster</code> tool.
342 343
</li></ul>

344 345 346 347 348 349 350 351 352 353 354 355
<h3>Detect Which Cluster Instances are Running</h3>
<p>
To find out which cluster nodes are currently running, execute the following SQL statement:
</p>
<pre>
SELECT VALUE FROM INFORMATION_SCHEMA.SETTINGS WHERE NAME='CLUSTER'
</pre>
<p>
If the result is <code>''</code> (two single quotes), then the cluster mode is disabled. Otherwise, the list of
servers is returned, enclosed in single quote. Example: <code>'server1:9191,server2:9191'</code>.
</p>

356 357 358 359 360
<h3>Clustering Algorithm and Limitations</h3>
<p>
Read-only queries are only executed against the first cluster node, but all other statements are
executed against all nodes. There is currently no load balancing made to avoid problems with
transactions. The following functions may yield different results on different cluster nodes and must be
361
executed with care: <code>RANDOM_UUID(), SECURE_RAND(), SESSION_ID(),
362 363
MEMORY_FREE(), MEMORY_USED(), CSVREAD(), CSVWRITE(), RAND()</code> [when not using a seed].
Those functions should not be used directly in modifying statements
364
(for example <code>INSERT, UPDATE, MERGE</code>). However, they can be used
365 366
in read-only statements and the result can then be used for modifying statements.
</p>
Thomas Mueller's avatar
Thomas Mueller committed
367 368 369 370 371
<p>
When using the cluster modes, result sets are read fully in memory by the client, so that
there is no problem if the server dies that executed the query. Result sets must fit in memory
on the client side.
</p>
372

Thomas Mueller's avatar
Thomas Mueller committed
373
<h2 id="two_phase_commit">Two Phase Commit</h2>
374 375 376 377 378 379 380
<p>
The two phase commit protocol is supported. 2-phase-commit works as follows:
</p>
<ul>
<li>Autocommit needs to be switched off
</li><li>A transaction is started, for example by inserting a row
</li><li>The transaction is marked 'prepared' by executing the SQL statement
381
    <code>PREPARE COMMIT transactionName</code>
382 383 384 385
</li><li>The transaction can now be committed or rolled back
</li><li>If a problem occurs before the transaction was successfully committed or rolled back
    (for example because a network problem occurred), the transaction is in the state 'in-doubt'
</li><li>When re-connecting to the database, the in-doubt transactions can be listed
386
    with <code>SELECT * FROM INFORMATION_SCHEMA.IN_DOUBT</code>
387
</li><li>Each transaction in this list must now be committed or rolled back by executing
388 389
    <code>COMMIT TRANSACTION transactionName</code> or
    <code>ROLLBACK TRANSACTION transactionName</code>
390 391 392
</li><li>The database needs to be closed and re-opened to apply the changes
</li></ul>

Thomas Mueller's avatar
Thomas Mueller committed
393
<h2 id="compatibility">Compatibility</h2>
394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410
<p>
This database is (up to a certain point) compatible to other databases such as HSQLDB, MySQL and PostgreSQL.
There are certain areas where H2 is incompatible.
</p>

<h3>Transaction Commit when Autocommit is On</h3>
<p>
At this time, this database engine commits a transaction (if autocommit is switched on) just before returning the result.
For a query, this means the transaction is committed even before the application scans through the result set, and before the result set is closed.
Other database engines may commit the transaction in this case when the result set is closed.
</p>

<h3>Keywords / Reserved Words</h3>
<p>
There is a list of keywords that can't be used as identifiers (table names, column names and so on),
unless they are quoted (surrounded with double quotes). The list is currently:
</p><p>
411
<code>
412
CROSS, CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP, DISTINCT, EXCEPT, EXISTS, FALSE,
413
FOR, FROM, FULL, GROUP, HAVING, INNER, INTERSECT, IS, JOIN, LIKE, LIMIT, MINUS, NATURAL, NOT, NULL,
Thomas Mueller's avatar
Thomas Mueller committed
414
ON, ORDER, PRIMARY, ROWNUM, SELECT, SYSDATE, SYSTIME, SYSTIMESTAMP, TODAY, TRUE, UNION,
415
UNIQUE, WHERE
416
</code>
417 418
</p><p>
Certain words of this list are keywords because they are functions that can be used without '()' for compatibility,
419
for example <code>CURRENT_TIMESTAMP</code>.
420 421
</p>

Thomas Mueller's avatar
Thomas Mueller committed
422
<h2 id="standards_compliance">Standards Compliance</h2>
423 424 425 426 427 428 429
<p>
This database tries to be as much standard compliant as possible. For the SQL language, ANSI/ISO is the main
standard. There are several versions that refer to the release date: SQL-92, SQL:1999, and SQL:2003.
Unfortunately, the standard documentation is not freely available. Another problem is that important features
are not standardized. Whenever this is the case, this database tries to be compatible to other databases.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
430
<h2 id="windows_service">Run as Windows Service</h2>
431 432
<p>
Using a native wrapper / adapter, Java applications can be run as a Windows Service.
433 434 435 436
There are various tools available to do that. The Java Service Wrapper from
<a href="http://wrapper.tanukisoftware.org">Tanuki Software, Inc.</a>
is included in the installation. Batch files are provided to install, start, stop and uninstall the
H2 Database Engine Service. This service contains the TCP Server and the H2 Console web application.
437
The batch files are located in the directory <code>h2/service</code>.
438 439 440 441 442
</p>

<h3>Install the Service</h3>
<p>
The service needs to be registered as a Windows Service first.
443
To do that, double click on <code>1_install_service.bat</code>.
444 445 446 447 448 449
If successful, a command prompt window will pop up and disappear immediately. If not, a message will appear.
</p>

<h3>Start the Service</h3>
<p>
You can start the H2 Database Engine Service using the service manager of Windows,
450
or by double clicking on <code>2_start_service.bat</code>.
451 452 453 454 455 456
Please note that the batch file does not print an error message if the service is not installed.
</p>

<h3>Connect to the H2 Console</h3>
<p>
After installing and starting the service, you can connect to the H2 Console application using a browser.
457
Double clicking on <code>3_start_browser.bat</code> to do that. The
458 459 460 461 462
default port (8082) is hard coded in the batch file.
</p>

<h3>Stop the Service</h3>
<p>
463
To stop the service, double click on <code>4_stop_service.bat</code>.
464 465 466 467 468
Please note that the batch file does not print an error message if the service is not installed or started.
</p>

<h3>Uninstall the Service</h3>
<p>
469
To uninstall the service, double click on <code>5_uninstall_service.bat</code>.
470 471 472
If successful, a command prompt window will pop up and disappear immediately. If not, a message will appear.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
473 474 475 476 477
<h3>Additional JDBC drivers</h3>
<p>
To use other databases (for example MySQL), the location of the JDBC drivers of those databases need to be
added to the environment variables <code>H2DRIVERS</code>  or <code>CLASSPATH</code> before
installing the service. Multiple drivers can be set; each entry needs to be separated with a <code>;</code>
Thomas Mueller's avatar
Thomas Mueller committed
478 479
(Windows) or <code>:</code>  (other operating systems). Spaces in the path names are supported.
The settings must not be quoted.
Thomas Mueller's avatar
Thomas Mueller committed
480 481
</p>

Thomas Mueller's avatar
Thomas Mueller committed
482
<h2 id="odbc_driver">ODBC Driver</h2>
483 484 485 486 487 488 489 490
<p>
This database does not come with its own ODBC driver at this time,
but it supports the PostgreSQL network protocol.
Therefore, the PostgreSQL ODBC driver can be used.
Support for the PostgreSQL network protocol is quite new and should be viewed
as experimental. It should not be used for production applications.
</p>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
491
To use the PostgreSQL ODBC driver on 64 bit versions of Windows,
492
first run <code>c:/windows/syswow64/odbcad32.exe</code>.
Thomas Mueller's avatar
Thomas Mueller committed
493 494 495
At this point you set up your DSN just like you would on any other system.
See also:
<a href="http://archives.postgresql.org/pgsql-odbc/2005-09/msg00125.php">Re: ODBC Driver on Windows 64 bit</a>
496 497 498 499 500
</p>

<h3>ODBC Installation</h3>
<p>
First, the ODBC driver must be installed.
501
Any recent PostgreSQL ODBC driver should work, however version 8.2 (<code>psqlodbc-08_02*</code>) or newer is recommended.
502 503 504 505 506 507 508 509
The Windows version of the PostgreSQL ODBC driver is available at
<a href="http://www.postgresql.org/ftp/odbc/versions/msi">http://www.postgresql.org/ftp/odbc/versions/msi</a>.
</p>

<h3>Starting the Server</h3>
<p>
After installing the ODBC driver, start the H2 Server using the command line:
</p>
510
<pre>
511 512 513 514 515
java -cp h2*.jar org.h2.tools.Server
</pre>
<p>
The PG Server (PG for PostgreSQL protocol) is started as well.
By default, databases are stored in the current working directory where the server is started.
516
Use <code>-baseDir</code> to save databases in another directory, for example the user home directory:
517
</p>
518
<pre>
519 520 521 522 523
java -cp h2*.jar org.h2.tools.Server -baseDir ~
</pre>
<p>
The PG server can be started and stopped from within a Java application as follows:
</p>
524
<pre>
Thomas Mueller's avatar
Thomas Mueller committed
525
Server server = Server.createPgServer("-baseDir", "~");
526 527 528 529 530 531
server.start();
...
server.stop();
</pre>
<p>
By default, only connections from localhost are allowed. To allow remote connections, use
532
<code>-pgAllowOthers</code> when starting the server.
533 534 535 536 537
</p>

<h3>ODBC Configuration</h3>
<p>
After installing the driver, a new Data Source must be added. In Windows,
538
run <code>odbcad32.exe</code> to open the Data Source Administrator. Then click on 'Add...'
539
and select the PostgreSQL Unicode driver. Then click 'Finish'.
540 541
You will be able to change the connection properties.
The property column represents the property key in the <code>odbc.ini</code> file
542
(which may be different from the GUI).
543 544 545 546
</p>
<table>
<tr><th>Property</th><th>Example</th><th>Remarks</th></tr>
<tr><td>Data Source</td><td>H2 Test</td><td>The name of the ODBC Data Source</td></tr>
547
<tr><td>Database</td><td>~/test;ifexists=true</td>
548
    <td>
549
        The database name. This can include connections settings.<br />
550 551 552 553
        By default, the database is stored in the current working directory <br />
        where the Server is started except when the -baseDir setting is used. <br />
        The name must be at least 3 characters.
    </td></tr>
554 555 556
<tr><td>Servername</td><td>localhost</td><td>The server name or IP address.<br />By default, only remote connections are allowed</td></tr>
<tr><td>Username</td><td>sa</td><td>The database user name.</td></tr>
<tr><td>SSL</td><td>false (disabled)</td><td>At this time, SSL is not supported.</td></tr>
557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572
<tr><td>Port</td><td>5435</td><td>The port where the PG Server is listening.</td></tr>
<tr><td>Password</td><td>sa</td><td>The database password.</td></tr>
</table>
<p>
To improve performance, please enable 'server side prepare' under Options / Datasource / Page 2 / Server side prepare.
</p>
<p>
Afterwards, you may use this data source.
</p>

<h3>PG Protocol Support Limitations</h3>
<p>
At this time, only a subset of the PostgreSQL network protocol is implemented.
Also, there may be compatibility problems on the SQL level, with the catalog, or with text encoding.
Problems are fixed as they are found.
Currently, statements can not be canceled when using the PG protocol.
Thomas Mueller's avatar
Thomas Mueller committed
573
Also, H2 does not provide index meta over ODBC.
574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589
</p>
<p>
PostgreSQL ODBC Driver Setup requires a database password; that means it
is not possible to connect to H2 databases without password. This is a limitation
of the ODBC driver.
</p>

<h3>Security Considerations</h3>
<p>
Currently, the PG Server does not support challenge response or encrypt passwords.
This may be a problem if an attacker can listen to the data transferred between the ODBC driver
and the server, because the password is readable to the attacker.
Also, it is currently not possible to use encrypted SSL connections.
Therefore the ODBC driver should not be used where security is important.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
590 591 592 593 594 595
<h3>Using Microsoft Access</h3>
<p>
When using Microsoft Access to edit data in a linked H2 table, you may need to enable the following option:
Tools - Options - Edit/Find - ODBC fields.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
596
<h2 id="microsoft_dot_net">Using H2 in Microsoft .NET</h2>
597 598 599 600 601 602 603 604 605 606 607 608 609 610 611
<p>
The database can be used from Microsoft .NET even without using Java, by using IKVM.NET.
You can access a H2 database on .NET using the JDBC API, or using the ADO.NET interface.
</p>

<h3>Using the ADO.NET API on .NET</h3>
<p>
An implementation of the ADO.NET interface is available in the open source project
<a href="http://code.google.com/p/h2sharp">H2Sharp</a>.
</p>

<h3>Using the JDBC API on .NET</h3>
<ul><li>Install the .NET Framework from <a href="http://www.microsoft.com">Microsoft</a>.
    Mono has not yet been tested.
</li><li>Install <a href="http://www.ikvm.net">IKVM.NET</a>.
612
</li><li>Copy the <code>h2*.jar</code> file to <code>ikvm/bin</code>
613
</li><li>Run the H2 Console using:
614
    <code>ikvm -jar h2*.jar</code>
615
</li><li>Convert the H2 Console to an <code>.exe</code> file using:
616
    <code>ikvmc -target:winexe h2*.jar</code>.
617
    You may ignore the warnings.
618
</li><li>Create a <code>.dll</code> file using (change the version accordingly):
619
    <code>ikvmc.exe -target:library -version:1.0.69.0 h2*.jar</code>
620 621
</li></ul>
<p>
622 623
If you want your C# application use H2, you need to add the <code>h2.dll</code> and the
<code>IKVM.OpenJDK.ClassLibrary.dll</code> to your C# solution. Here some sample code:
624
</p>
625
<pre>
626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644
using System;
using java.sql;

class Test
{
    static public void Main()
    {
        org.h2.Driver.load();
        Connection conn = DriverManager.getConnection("jdbc:h2:~/test", "sa", "sa");
        Statement stat = conn.createStatement();
        ResultSet rs = stat.executeQuery("SELECT 'Hello World'");
        while (rs.next())
        {
            Console.WriteLine(rs.getString(1));
        }
    }
}
</pre>

Thomas Mueller's avatar
Thomas Mueller committed
645
<h2 id="acid">ACID</h2>
646 647 648 649
<p>
In the database world, ACID stands for:
</p>
<ul>
Thomas Mueller's avatar
Thomas Mueller committed
650 651 652 653
<li>Atomicity: transactions must be atomic, meaning either all tasks are performed or none.
</li><li>Consistency: all operations must comply with the defined constraints.
</li><li>Isolation: transactions must be isolated from each other.
</li><li>Durability: committed transaction will not be lost.
654 655 656 657 658 659 660 661 662
</li></ul>

<h3>Atomicity</h3>
<p>
Transactions in this database are always atomic.
</p>

<h3>Consistency</h3>
<p>
663 664 665
By default, this database is always in a consistent state.
Referential integrity rules are enforced except when
explicitly disabled.
666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683
</p>

<h3>Isolation</h3>
<p>
For H2, as with most other database systems, the default isolation level is 'read committed'.
This provides better performance, but also means that transactions are not completely isolated.
H2 supports the transaction isolation levels 'serializable', 'read committed', and 'read uncommitted'.
</p>

<h3>Durability</h3>
<p>
This database does not guarantee that all committed transactions survive a power failure.
Tests show that all databases sometimes lose transactions on power failure (for details, see below).
Where losing transactions is not acceptable, a laptop or UPS (uninterruptible power supply) should be used.
If durability is required for all possible cases of hardware failure, clustering should be used,
such as the H2 clustering mode.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
684
<h2 id="durability_problems">Durability Problems</h2>
685 686 687 688 689
<p>
Complete durability means all committed transaction survive a power failure.
Some databases claim they can guarantee durability, but such claims are wrong.
A durability test was run against H2, HSQLDB, PostgreSQL, and Derby.
All of those databases sometimes lose committed transactions.
690
The test is included in the H2 download, see <code>org.h2.test.poweroff.Test</code>.
691 692 693 694 695 696 697
</p>

<h3>Ways to (Not) Achieve Durability</h3>
<p>
Making sure that committed transactions are not lost is more complicated than it seems first.
To guarantee complete durability, a database must ensure that the log record is on the hard drive
before the commit call returns. To do that, databases use different methods. One
698
is to use the 'synchronous write' file access mode. In Java, <code>RandomAccessFile</code>
699
supports the modes <code>rws</code> and <code>rwd</code>:
700 701
</p>
<ul>
702 703
<li><code>rwd</code>: every update to the file's content is written synchronously to the underlying storage device.
</li><li><code>rws</code>: in addition to <code>rwd</code>, every update to the metadata is written synchronously.</li>
704 705
</ul>
<p>
706
A test (<code>org.h2.test.poweroff.TestWrite</code>) with one of those modes achieves
707
around 50 thousand write operations per second.
708 709 710 711 712 713 714 715
Even when the operating system write buffer is disabled, the write rate is around 50 thousand operations per second.
This feature does not force changes to disk because it does not flush all buffers.
The test updates the same byte in the file again and again. If the hard drive was able to write at this rate,
then the disk would need to make at least 50 thousand revolutions per second, or 3 million RPM
(revolutions per minute). There are no such hard drives. The hard drive used for the test is about 7200 RPM,
or about 120 revolutions per second. There is an overhead, so the maximum write rate must be lower than that.
</p>
<p>
716
Calling <code>fsync</code> flushes the buffers. There are two ways to do that in Java:
717 718
</p>
<ul>
719
<li><code>FileDescriptor.sync()</code>. The documentation says that this forces all system
720
buffers to synchronize with the underlying device.
721
This method is supposed to return after all in-memory modified copies of buffers associated with this file descriptor
722
have been written to the physical medium.
723
</li><li><code>FileChannel.force()</code> (since JDK 1.4). This method is supposed
724
to force any updates to this channel's file to be written to the storage device that contains it.
725 726
</li></ul>
<p>
727
By default, MySQL calls <code>fsync</code> for each commit. When using one of those methods, only around 60 write operations
728
per second can be achieved, which is consistent with the RPM rate of the hard drive used.
729 730
Unfortunately, even when calling <code>FileDescriptor.sync()</code> or
<code>FileChannel.force()</code>,
731
data is not always persisted to the hard drive, because most hard drives do not obey
732
<code>fsync()</code>: see
733
<a href="http://hardware.slashdot.org/article.pl?sid=05/05/13/0529252">Your Hard Drive Lies to You</a>.
734
In Mac OS X, <code>fsync</code> does not flush hard drive buffers. See
735 736 737 738
<a href="http://lists.apple.com/archives/darwin-dev/2005/Feb/msg00072.html">Bad fsync?</a>.
So the situation is confusing, and tests prove there is a problem.
</p>
<p>
739
Trying to flush hard drive buffers is hard, and if you do the performance is very bad.
740 741 742 743 744 745 746
First you need to make sure that the hard drive actually flushes all buffers.
Tests show that this can not be done in a reliable way.
Then the maximum number of transactions is around 60 per second.
Because of those reasons, the default behavior of H2 is to delay writing committed transactions.
</p>
<p>
In H2, after a power failure, a bit more than one second of committed transactions may be lost.
747 748
To change the behavior, use <code>SET WRITE_DELAY</code> and
<code>CHECKPOINT SYNC</code>.
749 750 751 752 753 754 755
Most other databases support commit delay as well.
In the performance comparison, commit delay was used for all databases that support it.
</p>

<h3>Running the Durability Test</h3>
<p>
To test the durability / non-durability of this and other databases, you can use the test application
756
in the package <code>org.h2.test.poweroff</code>.
757
Two computers with network connection are required to run this test.
758 759 760 761 762 763 764 765 766 767 768
One computer just listens, while the test application is run (and power is cut) on the other computer.
The computer with the listener application opens a TCP/IP port and listens for an incoming connection.
The second computer first connects to the listener, and then created the databases and starts inserting
records. The connection is set to 'autocommit', which means after each inserted record a commit is performed
automatically. Afterwards, the test computer notifies the listener that this record was inserted successfully.
The listener computer displays the last inserted record number every 10 seconds. Now, switch off the power
manually, then restart the computer, and run the application again. You will find out that in most cases,
none of the databases contains all the records that the listener computer knows about. For details, please
consult the source code of the listener and test application.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
769
<h2 id="using_recover_tool">Using the Recover Tool</h2>
770
<p>
Thomas Mueller's avatar
Thomas Mueller committed
771 772
The <code>Recover</code> tool can be used to extract the contents of a database file, even if the database is corrupted.
It also extracts the content of the transaction log and large objects (CLOB or BLOB).
773 774
To run the tool, type on the command line:
</p>
775
<pre>
776
java -cp h2*.jar org.h2.tools.Recover
777 778 779
</pre>
<p>
For each database in the current directory, a text file will be created.
780
This file contains raw insert statements (for the data) and data definition (DDL) statements to recreate
781 782 783
the schema of the database. This file can be executed using the <code>RunScript</code> tool or a
<code>RUNSCRIPT FROM</code> SQL statement. The script includes at least one
<code>CREATE USER</code> statement. If you run the script against a database that was created with the same
784 785
user, or if there are conflicting users, running the script will fail. Consider running the script
against a database that was created with a user name that is not in the script.
786
</p>
787
<p>
Thomas Mueller's avatar
Thomas Mueller committed
788
The <code>Recover</code> tool creates a SQL script from database file. It also processes the transaction log.
789
</p>
790

Thomas Mueller's avatar
Thomas Mueller committed
791
<h2 id="file_locking_protocols">File Locking Protocols</h2>
792
<p>
Thomas Mueller's avatar
Thomas Mueller committed
793 794 795
Multiple concurrent connections to the same database are supported, however a database file
can only be open for reading and writing (in embedded mode) by one process at the same time.
Otherwise, the processes would overwrite each others data and corrupt the database file.
796
To protect against this problem, whenever a database is opened, a lock file is created
Thomas Mueller's avatar
Thomas Mueller committed
797 798
to signal other processes that the database is in use. If the database is closed, or if the process that opened
the database stops normally, this lock file is deleted.
799 800
</p><p>
In special cases (if the process did not terminate normally, for example because
801
there was a power failure), the lock file is not deleted by the process that created it.
802 803 804 805 806 807 808
That means the existence of the lock file is not a safe protocol for file locking.
However, this software uses a challenge-response protocol to protect the database
files. There are two methods (algorithms) implemented to provide both security
(that is, the same database files cannot be opened by two processes at the same time)
and simplicity (that is, the lock file does not need to be deleted manually by the user).
The two methods are 'file method' and 'socket methods'.
</p>
Thomas Mueller's avatar
Thomas Mueller committed
809 810
<p>
The file locking protocols have the following limitation: if a shared file system is used,
811
and the machine with the lock owner is sent to sleep (standby or hibernate),
Thomas Mueller's avatar
Thomas Mueller committed
812 813 814 815 816
another machine may take over. If the machine that originally held the lock
wakes up, the database may become corrupt. If this situation can occur,
the application must ensure the database is closed when the application
is put to sleep.
</p>
817 818 819 820 821 822

<h3>File Locking Method 'File'</h3>
<p>
The default method for database file locking is the 'File Method'. The algorithm is:
</p>
<ul>
823
<li>If the lock file does not exist, it is created (using the atomic operation
824
<code>File.createNewFile</code>).
825
Then, the process waits a little bit (20 ms) and checks the file again. If the file was changed
826
during this time, the operation is aborted. This protects against a race condition
827
when one process deletes the lock file just after another one create it, and a third process creates
828 829 830 831 832 833 834 835 836 837 838
the file again. It does not occur if there are only two writers.
</li><li>
If the file can be created, a random number is inserted together with the locking method
('file'). Afterwards, a watchdog thread is started that
checks regularly (every second once by default) if the file was deleted or modified by
another (challenger) thread / process. Whenever that occurs, the file is overwritten with the
old data. The watchdog thread runs with high priority so that a change to the lock file does
not get through undetected even if the system is very busy. However, the watchdog thread
does use very little resources (CPU time), because it waits most of the time. Also, the watchdog only reads from the hard disk
and does not write to it.
</li><li>
839
If the lock file exists and was recently modified, the process waits for some time (up to two seconds).
840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860
If it was still changed, an exception is thrown (database is locked). This is done to eliminate race conditions with many concurrent
writers. Afterwards, the file is overwritten with a new version (challenge).
After that, the thread waits for 2 seconds.
If there is a watchdog thread protecting the file, he will overwrite the change
and this process will fail to lock the database.
However, if there is no watchdog thread, the lock file will still be as written by
this thread. In this case, the file is deleted and atomically created again.
The watchdog thread is started in this case and the file is locked.
</li></ul>
<p>
This algorithm is tested with over 100 concurrent threads. In some cases, when there are
many concurrent threads trying to lock the database, they block each other (meaning
the file cannot be locked by any of them) for some time. However, the file never gets
locked by two threads at the same time. However using that many concurrent threads
/ processes is not the common use case. Generally, an application should throw an error
to the user if it cannot open a database, and not try again in a (fast) loop.
</p>

<h3>File Locking Method 'Socket'</h3>
<p>
There is a second locking mechanism implemented, but disabled by default.
861
To use it, append <code>;FILE_LOCK=SOCKET</code> to the database URL.
862 863 864 865 866 867 868 869 870 871 872 873
The algorithm is:
</p>
<ul>
<li>If the lock file does not exist, it is created.
Then a server socket is opened on a defined port, and kept open.
The port and IP address of the process that opened the database is written
into the lock file.
</li><li>If the lock file exists, and the lock method is 'file', then the software switches
to the 'file' method.
</li><li>If the lock file exists, and the lock method is 'socket', then the process
checks if the port is in use. If the original process is still running, the port is in use
and this process throws an exception (database is in use). If the original process
874
died (for example due to a power failure, or abnormal termination of the virtual machine),
875 876 877 878 879 880 881 882 883
then the port was released. The new process deletes the lock file and starts again.
</li></ul>
<p>
This method does not require a watchdog thread actively polling (reading) the same
file every second. The problem with this method is, if the file is stored on a network
share, two processes (running on different computers) could still open the same
database files, if they do not have a direct TCP/IP connection.
</p>

884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899
<h2 id="file_locking_serialized">File Locking Method 'Serialized'</h2>
<p>
This locking mode allows to open multiple connections to the same database.
The connections may be opened from multiple processes and from different computers.
When writing to the database, access is automatically synchronized internally. Write operations
are slower than when using the server mode, and concurrency is relatively poor.
The advantage of this mode is that there is no need to start a server.
</p>
<p>
To enable this feature, append <code>;FILE_LOCK=SERIALIZED</code> to the database URL.
</p>
<p>
This feature is relatively new. When using it for production, please ensure
your use case is well tested (if possible with automated test cases).
</p>

Thomas Mueller's avatar
Thomas Mueller committed
900
<h2 id="sql_injection">Protection against SQL Injection</h2>
901 902 903 904 905 906
<h3>What is SQL Injection</h3>
<p>
This database engine provides a solution for the security vulnerability known as 'SQL Injection'.
Here is a short description of what SQL injection means.
Some applications build SQL statements with embedded user input such as:
</p>
907
<pre>
908 909 910 911 912 913
String sql = "SELECT * FROM USERS WHERE PASSWORD='"+pwd+"'";
ResultSet rs = conn.createStatement().executeQuery(sql);
</pre>
<p>
If this mechanism is used anywhere in the application, and user input is not correctly filtered or encoded,
it is possible for a user to inject SQL functionality or statements by using specially built input
914
such as (in this example) this password: <code>' OR ''='</code>.
915
In this case the statement becomes:
916
</p>
917
<pre>
918 919 920 921
SELECT * FROM USERS WHERE PASSWORD='' OR ''='';
</pre>
<p>
Which is always true no matter what the password stored in the database is.
922
For more information about SQL Injection, see <a href="#glossary_links">Glossary and Links</a>.
923 924 925 926 927
</p>

<h3>Disabling Literals</h3>
<p>
SQL Injection is not possible if user input is not directly embedded in SQL statements.
928
A simple solution for the problem above is to use a prepared statement:
929
</p>
930
<pre>
931 932 933 934 935 936 937 938 939 940
String sql = "SELECT * FROM USERS WHERE PASSWORD=?";
PreparedStatement prep = conn.prepareStatement(sql);
prep.setString(1, pwd);
ResultSet rs = prep.executeQuery();
</pre>
<p>
This database provides a way to enforce usage of parameters when passing user input
to the database. This is done by disabling embedded literals in SQL statements.
To do this, execute the statement:
</p>
941
<pre>
942 943 944 945
SET ALLOW_LITERALS NONE;
</pre>
<p>
Afterwards, SQL statements with text and number literals are not allowed any more.
946 947
That means, SQL statement of the form <code>WHERE NAME='abc'</code>
or <code>WHERE CustomerId=10</code> will fail.
948
It is still possible to use prepared statements and parameters as described above. Also, it is still possible to generate
949 950
SQL statements dynamically, and use the Statement API, as long as the SQL statements
do not include literals.
951
There is also a second mode where number literals are allowed:
952 953
<code>SET ALLOW_LITERALS NUMBERS</code>.
To allow all literals, execute <code>SET ALLOW_LITERALS ALL</code>
954
(this is the default setting). Literals can only be enabled or disabled by an administrator.
955 956 957 958 959
</p>

<h3>Using Constants</h3>
<p>
Disabling literals also means disabling hard-coded 'constant' literals. This database supports
960
defining constants using the <code>CREATE CONSTANT</code> command.
961
Constants can be defined only
962 963 964
when literals are enabled, but used even when literals are disabled. To avoid name clashes
with column names, constants can be defined in other schemas:
</p>
965
<pre>
966 967 968 969 970 971 972 973 974 975 976 977 978
CREATE SCHEMA CONST AUTHORIZATION SA;
CREATE CONSTANT CONST.ACTIVE VALUE 'Active';
CREATE CONSTANT CONST.INACTIVE VALUE 'Inactive';
SELECT * FROM USERS WHERE TYPE=CONST.ACTIVE;
</pre>
<p>
Even when literals are enabled, it is better to use constants instead
of hard-coded number or text literals in queries or views. With constants, typos are found at compile
time, the source code is easier to understand and change.
</p>

<h3>Using the ZERO() Function</h3>
<p>
979
It is not required to create a constant for the number 0 as there is already a built-in function <code>ZERO()</code>:
980
</p>
981
<pre>
982 983 984
SELECT * FROM USERS WHERE LENGTH(PASSWORD)=ZERO();
</pre>

Thomas Mueller's avatar
Thomas Mueller committed
985
<h2 id="remote_access">Protection against Remote Access</h2>
986
<p>
987
By default this database does not allow connections from other machines when starting the H2 Console,
988
the TCP server, or the PG server. Remote access can be enabled using the command line
989
options <code>-webAllowOthers, -tcpAllowOthers, -pgAllowOthers</code>.
990
If you enable remote access, please also consider using the options
991
<code>-baseDir, -ifExists</code>, so that remote
Thomas Mueller's avatar
Thomas Mueller committed
992
users can not create new databases or access existing databases with weak passwords.
993 994
When using the option <code>-baseDir</code>, only databases within that directory may be accessed.
Ensure the existing accessible databases are protected using strong passwords.
995 996
</p>

Thomas Mueller's avatar
Thomas Mueller committed
997
<h2 id="restricting_classes">Restricting Class Loading and Usage</h2>
998 999
<p>
By default there is no restriction on loading classes and executing Java code for admins.
1000
That means an admin may call system functions such as
1001
<code>System.setProperty</code> by executing:
1002
</p>
1003
<pre>
1004 1005 1006 1007 1008 1009 1010
CREATE ALIAS SET_PROPERTY FOR "java.lang.System.setProperty";
CALL SET_PROPERTY('abc', '1');
CREATE ALIAS GET_PROPERTY FOR "java.lang.System.getProperty";
CALL GET_PROPERTY('abc');
</pre>
<p>
To restrict users (including admins) from loading classes and executing code,
1011
the list of allowed classes can be set in the system property
1012
<code>h2.allowedClasses</code>
1013
in the form of a comma separated list of classes or patterns (items ending with <code>*</code>).
1014 1015
By default all classes are allowed. Example:
</p>
1016
<pre>
1017 1018 1019 1020 1021 1022 1023 1024
java -Dh2.allowedClasses=java.lang.Math,com.acme.*
</pre>
<p>
This mechanism is used for all user classes, including database event listeners,
trigger classes, user-defined functions, user-defined aggregate functions, and JDBC
driver classes (with the exception of the H2 driver) when using the H2 Console.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1025
<h2 id="security_protocols">Security Protocols</h2>
1026 1027 1028 1029 1030 1031 1032 1033 1034
<p>
The following paragraphs document the security protocols used in this database.
These descriptions are very technical and only intended for security experts that already know
the underlying security primitives.
</p>

<h3>User Password Encryption</h3>
<p>
When a user tries to connect to a database, the combination of
1035
user name, @, and password are hashed using SHA-256, and this hash value
1036
is transmitted to the database.
1037
This step does not protect against an attacker that re-uses the value if he is able to listen to the
1038 1039 1040 1041 1042 1043 1044 1045
(unencrypted) transmission between the client and the server.
But, the passwords are never transmitted as plain text,
even when using an unencrypted connection between client and server.
That means if a user reuses the same password for different things,
this password is still protected up to some point. See also
'RFC 2617 - HTTP Authentication: Basic and Digest Access Authentication'
for more information.
</p><p>
Thomas Mueller's avatar
Thomas Mueller committed
1046 1047 1048
When a new database or user is created, a new random salt value is generated.
The size of the salt is 64 bits. Using the random salt reduces the risk of an
attacker pre-calculating hash values for many different (commonly used) passwords.
1049 1050 1051 1052
</p><p>
The combination of user-password hash value (see above) and salt is hashed
using SHA-256. The resulting value is stored in the database.
When a user tries to connect to the database, the database combines
1053
user-password hash value with the stored salt value and calculates the
1054 1055 1056 1057 1058 1059
hash value. Other products use multiple iterations (hash the hash value again and again),
but this is not done in this product to reduce the risk of denial of service attacks
(where the attacker tries to connect with bogus passwords, and the server
spends a lot of time calculating the hash value for each password).
The reasoning is: if the attacker has access to the hashed passwords, he also has
access to the data in plain text, and therefore does not need the password any more.
1060 1061
If the data is protected by storing it on another computer and only accessible remotely,
then the iteration count is not required at all.
1062 1063 1064 1065 1066 1067
</p>

<h3>File Encryption</h3>
<p>
The database files can be encrypted using two different algorithms: AES-128 and
XTEA (using 32 rounds). The reasons for supporting XTEA is performance
Thomas Mueller's avatar
Thomas Mueller committed
1068 1069
(XTEA is a bit faster as AES in some environments) and to have an alternative algorithm if AES is suddenly broken.
Please note that the XTEA implementation used in this database only uses 32 rounds
Thomas Mueller's avatar
Thomas Mueller committed
1070
and not 64 rounds as recommended by its inventor (as of 2010, the best known attack is on 27 rounds).
1071
</p><p>
1072 1073
When a user tries to connect to an encrypted database, the combination of
<code>file@</code> and the file password is hashed using SHA-256. This hash value is
1074 1075 1076
transmitted to the server.
</p><p>
When a new database file is created, a new cryptographically secure
1077
random salt value is generated. The size of the salt is 64 bits.
1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088
The combination of the file password hash and the salt value is hashed 1024 times
using SHA-256. The reason for the iteration is to make it harder for an attacker to
calculate hash values for common passwords.
</p><p>
The resulting hash value is used as the key for the block cipher algorithm
(AES-128 or XTEA with 32 rounds). Then, an initialization vector (IV) key
is calculated by hashing the key again using SHA-256.
This is to make sure the IV is unknown to the attacker.
The reason for using a secret IV is to protect against watermark attacks.
</p><p>
Before saving a block of data (each block is 8 bytes long), the following operations are executed:
Thomas Mueller's avatar
Thomas Mueller committed
1089
first, the IV is calculated by encrypting the block number with the IV key (using the same
1090 1091 1092 1093 1094 1095
block cipher algorithm). This IV is combined with the plain text using XOR. The resulting data is
encrypted using the AES-128 or XTEA algorithm.
</p><p>
When decrypting, the operation is done in reverse. First, the block is decrypted using the key,
and then the IV is calculated combined with the decrypted text using XOR.
</p><p>
1096 1097
Therefore, the block cipher mode of operation is CBC (cipher-block chaining), but each chain
is only one block long. The advantage over the ECB (electronic codebook) mode is that patterns
1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109
in the data are not revealed, and the advantage over multi block CBC is that flipped cipher text bits
are not propagated to flipped plaintext bits in the next block.
</p><p>
Database encryption is meant for securing the database while it is not in use (stolen laptop and so on).
It is not meant for cases where the attacker has access to files while the database is in use.
When he has write access, he can for example replace pieces of files with pieces of older versions
and manipulate data like this.
</p><p>
File encryption slows down the performance of the database engine. Compared to unencrypted mode,
database operations take about 2.2 times longer when using XTEA, and 2.5 times longer using AES (embedded mode).
</p>

1110
<h3>Wrong Password / User Name Delay</h3>
1111 1112
<p>
To protect against remote brute force password attacks, the delay after each unsuccessful
1113 1114
login gets double as long. Use the system properties <code>h2.delayWrongPasswordMin</code>
and <code>h2.delayWrongPasswordMax</code> to change the minimum (the default is 250 milliseconds)
1115 1116
or maximum delay (the default is 4000 milliseconds, or 4 seconds). The delay only
applies for those using the wrong password. Normally there is no delay for a user that knows the correct
1117
password, with one exception: after using the wrong password, there is a delay of up to (randomly distributed)
1118 1119 1120 1121
the same delay as for a wrong password. This is to protect against parallel brute force attacks,
so that an attacker needs to wait for the whole delay. Delays are synchronized. This is also required
to protect against parallel attacks.
</p>
1122 1123 1124 1125 1126
<p>
There is only one exception message for both wrong user and for wrong password,
to make it harder to get the list of user names. It is not possible from the stack trace to see
if the user name was wrong or the password.
</p>
1127 1128 1129

<h3>HTTPS Connections</h3>
<p>
1130
The web server supports HTTP and HTTPS connections using <code>SSLServerSocket</code>.
1131 1132 1133 1134
There is a default self-certified certificate to support an easy starting point, but
custom certificates are supported as well.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1135
<h2 id="ssl_tls_connections">SSL/TLS Connections</h2>
1136 1137
<p>
Remote SSL/TLS connections are supported using the Java Secure Socket Extension
1138 1139
(<code>SSLServerSocket, SSLSocket</code>). By default, anonymous SSL is enabled.
The default cipher suite is <code>SSL_DH_anon_WITH_RC4_128_MD5</code>.
1140 1141
</p>
<p>
1142 1143
To use your own keystore, set the system properties <code>javax.net.ssl.keyStore</code> and
<code>javax.net.ssl.keyStorePassword</code> before starting the H2 server and client.
1144 1145 1146 1147 1148
See also <a href="http://java.sun.com/javase/6/docs/technotes/guides/security/jsse/JSSERefGuide.html#CustomizingStores">
Customizing the Default Key and Trust Stores, Store Types, and Store Passwords</a>
for more information.
</p>
<p>
1149
To disable anonymous SSL, set the system property <code>h2.enableAnonymousSSL</code> to false.
1150 1151
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1152
<h2 id="uuid">Universally Unique Identifiers (UUID)</h2>
1153
<p>
Thomas Mueller's avatar
Thomas Mueller committed
1154
This database supports UUIDs. Also supported is a function to create new UUIDs using
1155 1156 1157 1158 1159
a cryptographically strong pseudo random number generator.
With random UUIDs, the chance of two having the same value can be calculated
using the probability theory. See also 'Birthday Paradox'.
Standardized randomly generated UUIDs have 122 random bits.
4 bits are used for the version (Randomly generated UUID), and 2 bits for the variant (Leach-Salz).
1160
This database supports generating such UUIDs using the built-in function
1161
<code>RANDOM_UUID()</code>.
1162 1163 1164
Here is a small program to estimate the probability of having two identical UUIDs
after generating a number of values:
</p>
1165
<pre>
1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176
public class Test {
    public static void main(String[] args) throws Exception {
        double x = Math.pow(2, 122);
        for (int i = 35; i &lt; 62; i++) {
            double n = Math.pow(2, i);
            double p = 1 - Math.exp(-(n * n) / 2 / x);
            System.out.println("2^" + i + "=" + (1L &lt;&lt; i) +
                    " probability: 0" +
                    String.valueOf(1 + p).substring(1));
        }
    }
1177 1178 1179 1180 1181
}
</pre>
<p>
Some values are:
</p>
1182 1183 1184 1185 1186 1187
<table>
<tr><th>Number of UUIs</th><th>Probability of Duplicates</th></tr>
<tr><td>2^36=68'719'476'736</td><td>0.000'000'000'000'000'4</td></tr>
<tr><td>2^41=2'199'023'255'552</td><td>0.000'000'000'000'4</td></tr>
<tr><td>2^46=70'368'744'177'664</td><td>0.000'000'000'4</td></tr>
</table>
1188 1189
<p>
To help non-mathematicians understand what those numbers mean, here a comparison:
Thomas Mueller's avatar
Thomas Mueller committed
1190
one's annual risk of being hit by a meteorite is estimated to be one chance in 17 billion,
1191 1192 1193
that means the probability is about 0.000'000'000'06.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253
<h2 id="recursive_queries">Recursive Queries</h2>
<p>
H2 has experimental support for recursive queries, using so called "common table expressions".
Examples:
</p>
<pre>
WITH RECURSIVE T(N) AS (
    SELECT 1
    UNION ALL
    SELECT N+1 FROM T WHERE N&lt;10
)
SELECT * FROM T;
-- returns the values 1 .. 10

WITH RECURSIVE T(N) AS (
    SELECT 1
    UNION ALL
    SELECT N*2 FROM T WHERE N&lt;10
)
SELECT * FROM T;
-- returns the values 1, 2, 4, 8, 16

CREATE TABLE FOLDER(ID INT PRIMARY KEY, NAME VARCHAR(255), PARENT INT);

INSERT INTO FOLDER VALUES(1, null, null), (2, 'src', 1),
(3, 'main', 2), (4, 'org', 3), (5, 'test', 2);

WITH LINK(ID, NAME, LEVEL) AS (
    SELECT ID, NAME, 0 FROM FOLDER WHERE PARENT IS NULL
    UNION ALL
    SELECT FOLDER.ID, IFNULL(LINK.NAME || '/', '') || FOLDER.NAME, LEVEL + 1
    FROM LINK INNER JOIN FOLDER ON LINK.ID = FOLDER.PARENT
)
SELECT NAME FROM LINK WHERE NAME IS NOT NULL ORDER BY ID;
-- src
-- src/main
-- src/main/org
-- src/test
</pre>
<p>
Limitations: Recursive queries need to be of the type <code>UNION ALL</code>,
and the recursion needs to be on the second part of the query.
No tables or views with the name of the table expression may exist.
Different table expression names need to be used when using multiple distinct table
expressions within the same transaction and for the same session.
All columns of the table expression are of type <code>VARCHAR</code>.
Parameters are only supported within the last <code>SELECT</code> statement
(a workaround is to use session variables like <code>@start</code>
within the table expression).
The syntax is:
</p>
<pre>
WITH RECURSIVE recursiveQueryName(columnName, ...) AS (
    nonRecursiveSelect
    UNION ALL
    recursiveSelect
)
select
</pre>

Thomas Mueller's avatar
Thomas Mueller committed
1254
<h2 id="system_properties">Settings Read from System Properties</h2>
1255 1256
<p>
Some settings of the database can be set on the command line using
1257
<code>-DpropertyName=value</code>. It is usually not required to change those settings manually.
1258 1259 1260
The settings are case sensitive.
Example:
</p>
1261
<pre>
1262 1263 1264 1265
java -Dh2.serverCachedObjects=256 org.h2.tools.Server
</pre>
<p>
The current value of the settings can be read in the table
1266
<code>INFORMATION_SCHEMA.SETTINGS</code>.
1267 1268 1269 1270 1271 1272
</p>
<p>
For a complete list of settings, see
<a href="../javadoc/org/h2/constant/SysProperties.html">SysProperties</a>.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1273
<h2 id="server_bind_address">Setting the Server Bind Address</h2>
1274 1275 1276
<p>
Usually server sockets accept connections on any/all local addresses.
This may be a problem on multi-homed hosts.
1277
To bind only to one address, use the system property <code>h2.bindAddress</code>.
1278 1279 1280 1281
This setting is used for both regular server sockets and for SSL server sockets.
IPv4 and IPv6 address formats are supported.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1282
<h2 id="file_system">Pluggable File System</h2>
1283 1284 1285 1286
<p>
This database supports a pluggable file system API. The file system implementation
is selected using a file name prefix. The following file systems are included:
</p>
1287
<ul><li><code>zip:</code>  read-only zip-file based file system. Format: <code>zip:/zipFileName!/fileName</code>.
Thomas Mueller's avatar
Thomas Mueller committed
1288
</li><li><code>split:</code> file system that splits files in 1 GB files (stackable with other file systems).
1289 1290
</li><li><code>nio:</code> file system that uses <code>FileChannel</code> instead of <code>RandomAccessFile</code> (faster in some operating systems).
</li><li><code>nioMapped:</code> file system that uses memory mapped files (faster in some operating systems).
Thomas Mueller's avatar
Thomas Mueller committed
1291 1292
    Please note that there currently is a file size limitation of 2 GB when using this file system.
    To work around this limitation, combine it with the split file system: <code>split:nioMapped:test</code>.
Thomas Mueller's avatar
Thomas Mueller committed
1293 1294
</li><li><code>memFS:</code> in-memory file system (slower than mem; experimental; mainly used for testing the database engine itself).
</li><li><code>memLZF:</code> compressing in-memory file system (slower than memFS but uses less memory; experimental; mainly used for testing the database engine itself).
1295 1296
</li></ul>
<p>
1297 1298
As an example, to use the the <code>nio</code> file system, use the following database URL:
<code>jdbc:h2:nio:~/test</code>.
1299 1300
</p>
<p>
1301 1302
To register a new file system, extend the classes <code>org.h2.store.fs.FileSystem, FileObject</code>,
and call the method <code>FileSystem.register</code> before using it.
1303 1304
</p>

1305 1306 1307 1308 1309 1310 1311 1312
<h2 id="database_upgrade">Database Upgrade</h2>
<p>
In version 1.2, H2 introduced a new file store implementation which is incompatible to the one used in versions &lt; 1.2.
To automatically convert databases to the new file store, it is necessary to include an additional jar file.
The file can be found at <a href="http://h2database.com/h2mig_pagestore_addon.jar">http://h2database.com/h2mig_pagestore_addon.jar</a> .
If this file is in the classpath, every connect to an older database will result in a conversion process.
</p>
<p>
1313
The conversion itself is done internally via <code>'script to'</code> and <code>'runscript from'</code>. After the conversion process, the files will be
1314 1315
renamed from
<ul>
1316 1317
<li><code>dbName.data.db</code> to <code>dbName.data.db.backup</code>
</li><li><code>dbName.index.db</code> to <code>dbName.index.db.backup</code>
1318 1319 1320 1321
</li></ul>
by default. Also, the temporary script will be written to the database directory instead of a temporary directory.
Both defaults can be customized via
<ul>
1322 1323
<li><code>org.h2.upgrade.DbUpgradeNonPageStoreToCurrent.setDeleteOldDb(boolean)</code>
</li><li><code>org.h2.upgrade.DbUpgradeNonPageStoreToCurrent.setScriptInTmpDir(boolean)</code>
1324 1325 1326
</li></ul>
prior opening a database connection.
</p>
1327 1328 1329 1330
<p>
Since version 1.2.140 it is possible to let the old h2 classes (v 1.2.128) connect to the database. The automatic upgrade .jar file must be present, and the url
must contain NO_UPGRADE=TRUE.
</p>
1331

Thomas Mueller's avatar
Thomas Mueller committed
1332
<h2 id="limits_limitations">Limits and Limitations</h2>
1333 1334 1335 1336
<p>
This database has the following known limitations:
</p>
<ul>
1337
<li>Database file size limits (excluding BLOB and CLOB data):
Thomas Mueller's avatar
Thomas Mueller committed
1338 1339 1340
    With the default storage mechanism, the maximum file size is currently 256 GB for the data, and 256 GB for the index.
    With the page store (experimental): 4 TB or higher.
</li><li>BLOB and CLOB size limit: every CLOB or BLOB can be up to 256 GB.
1341
</li><li>The maximum file size for FAT or FAT32 file systems is 4 GB. That means when using FAT or FAT32,
1342
the limit is 4 GB for the data. This is the limitation of the file system. The database does provide a
1343
workaround for this problem, it is to use the file name prefix <code>split:</code>. In that case files are split into
1344
files of 1 GB by default. An example database URL is:
1345
<code>jdbc:h2:split:~/test</code>.
Thomas Mueller's avatar
Thomas Mueller committed
1346
</li><li>The maximum number of rows per table is 2'147'483'648.
1347
</li><li>Main memory requirements: The larger the database, the more main memory is required.
christian.peter.io's avatar
christian.peter.io committed
1348 1349
    With the version 1.1 storage mechanism, the minimum main memory required for a 12 GB database was around 240 MB.
    With the current page store, the minimum main memory required is much lower, around 1 MB for each 8 GB database file size.
Thomas Mueller's avatar
Thomas Mueller committed
1350
</li><li>Limit on the complexity of SQL statements.
1351
Statements of the following form will result in a stack overflow exception:
1352
<pre>
1353 1354 1355 1356 1357
SELECT * FROM DUAL WHERE X = 1
OR X = 2 OR X = 2 OR X = 2 OR X = 2 OR X = 2
-- repeat previous line 500 times --
</pre>
</li><li>There is no limit for the following entities, except the memory and storage capacity:
Thomas Mueller's avatar
Thomas Mueller committed
1358 1359 1360 1361 1362 1363
    maximum identifier length (table name, column name, and so on);
    maximum number of tables, columns, indexes, triggers, and other database objects;
    maximum statement length, number of parameters per statement, tables per statement, expressions
    in order by, group by, having, and so on;
    maximum rows per query;
    maximum columns per table, columns per index, indexes per table, lob columns per table, and so on;
1364
    maximum row length, index row length, select row length;
Thomas Mueller's avatar
Thomas Mueller committed
1365
    maximum length of a varchar column, decimal column, literal in a statement.
1366 1367 1368 1369
</li><li>For limitations on data types, see the documentation of the respective Java data type
    or the data type documentation of this database.
</li></ul>

Thomas Mueller's avatar
Thomas Mueller committed
1370
<h2 id="glossary_links">Glossary and Links</h2>
Thomas Mueller's avatar
Thomas Mueller committed
1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423 1424 1425 1426 1427 1428
<table>
    <tr>
        <th>Term</th>
        <th>Description</th>
    </tr>
    <tr>
        <td>AES-128</td>
        <td>A block encryption algorithm. See also: <a
            href="http://en.wikipedia.org/wiki/Advanced_Encryption_Standard">Wikipedia:
        AES</a></td>
    </tr>
    <tr>
        <td>Birthday Paradox</td>
        <td>Describes the higher than expected probability that two
        persons in a room have the same birthday. Also valid for randomly
        generated UUIDs. See also: <a
            href="http://en.wikipedia.org/wiki/Birthday_paradox">Wikipedia:
        Birthday Paradox</a></td>
    </tr>
    <tr>
        <td>Digest</td>
        <td>Protocol to protect a password (but not to protect data).
        See also: <a href="http://www.faqs.org/rfcs/rfc2617.html">RFC
        2617: HTTP Digest Access Authentication</a></td>
    </tr>
    <tr>
        <td>GCJ</td>
        <td>Compiler for Java. <a href="http://gcc.gnu.org/java">GNU
        Compiler for the Java</a> and <a
            href="http://www.dobysoft.com/products/nativej">NativeJ
        (commercial)</a></td>
    </tr>
    <tr>
        <td>HTTPS</td>
        <td>A protocol to provide security to HTTP connections. See
        also: <a href="http://www.ietf.org/rfc/rfc2818.txt">RFC 2818:
        HTTP Over TLS</a></td>
    </tr>
    <tr>
        <td>Modes of Operation</td>
        <td><a
            href="http://en.wikipedia.org/wiki/Block_cipher_modes_of_operation">Wikipedia:
        Block cipher modes of operation</a></td>
    </tr>
    <tr>
        <td>Salt</td>
        <td>Random number to increase the security of passwords. See
        also: <a href="http://en.wikipedia.org/wiki/Key_derivation_function">Wikipedia:
        Key derivation function</a></td>
    </tr>
    <tr>
        <td>SHA-256</td>
        <td>A cryptographic one-way hash function. See also: <a
            href="http://en.wikipedia.org/wiki/SHA_family">Wikipedia: SHA
        hash functions</a></td>
    </tr>
    <tr>
        <td>SQL Injection</td>
1429 1430
        <td>A security vulnerability where an application embeds SQL
        statements or expressions in user input. See also: <a
Thomas Mueller's avatar
Thomas Mueller committed
1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447 1448 1449 1450 1451
            href="http://en.wikipedia.org/wiki/SQL_injection">Wikipedia:
        SQL Injection</a></td>
    </tr>
    <tr>
        <td>Watermark Attack</td>
        <td>Security problem of certain encryption programs where the
        existence of certain data can be proven without decrypting. For more
        information, search in the internet for 'watermark attack
        cryptoloop'</td>
    </tr>
    <tr>
        <td>SSL/TLS</td>
        <td>Secure Sockets Layer / Transport Layer Security. See also:
        <a href="http://java.sun.com/products/jsse/">Java Secure Socket
        Extension (JSSE)</a></td>
    </tr>
    <tr>
        <td>XTEA</td>
        <td>A block encryption algorithm. See also: <a
            href="http://en.wikipedia.org/wiki/XTEA">Wikipedia: XTEA</a></td>
    </tr>
1452 1453 1454
</table>

<!-- [close] { --></div></td></tr></table><!-- } --><!-- analytics --></body></html>