advanced.html 63.2 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 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50
<a href="#result_sets">
    Result Sets</a><br />
<a href="#large_objects">
    Large Objects</a><br />
<a href="#linked_tables">
    Linked Tables</a><br />
<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 />
51 52
<a href="#file_locking_serialized">
    File Locking Method 'Serialized'</a><br />
53 54
<a href="#sql_injection">
    Protection against SQL Injection</a><br />
55 56
<a href="#remote_access">
    Protection against Remote Access</a><br />
57 58 59 60 61 62 63 64 65 66 67 68
<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 />
69 70
<a href="#file_system">
    Pluggable File System</a><br />
71 72
<a href="#database_upgrade">
    Database Upgrade</a><br />
Thomas Mueller's avatar
Thomas Mueller committed
73 74
<a href="#limits_limitations">
    Limits and Limitations</a><br />
75 76 77
<a href="#glossary_links">
    Glossary and Links</a><br />

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

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

86 87 88 89 90 91
<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.
92 93 94
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>.
95 96 97 98
</p>

<h3>Large Result Sets and External Sorting</h3>
<p>
99
For large result set, the result is buffered to disk. The threshold can be defined using the statement
100 101
<code>SET MAX_MEMORY_ROWS</code>.
If <code>ORDER BY</code> is used, the sorting is done using an
102 103 104
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.
105 106
</p>

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

<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.
114 115 116
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>.
117 118
When using the client/server mode, large BLOB and CLOB data is stored in a temporary file
on the client side.
119 120
</p>

121 122 123 124
<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
125
<a href="grammar.html#set_max_length_inplace_lob" class="notranslate" >MAX_LENGTH_INPLACE_LOB</a>,
126 127 128 129 130 131 132 133 134
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>
135 136
CLOB and BLOB values can be compressed by using
<a href="grammar.html#set_compress_lob" class="notranslate" >SET COMPRESS_LOB</a>.
137 138 139 140 141
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
142
<h2 id="linked_tables">Linked Tables</h2>
143 144
<p>
This database supports linked tables, which means tables that don't exist in the current database but
145
are just links to another database. To create such a link, use the
146
<code>CREATE LINKED TABLE</code> statement:
147
</p>
148
<pre>
149 150 151 152 153
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.
154 155
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>.
156 157 158 159 160 161 162 163
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
164
is shared. To disable this, set the system property <code>h2.shareLinkedConnections=false</code>.
165 166
</p>
<p>
167 168
The statement <a href="grammar.html#create_linked_table" class="notranslate" >CREATE LINKED TABLE</a>
supports an optional schema name parameter.
169 170
</p>

Thomas Mueller's avatar
Thomas Mueller committed
171
<h2 id="transaction_isolation">Transaction Isolation</h2>
172 173 174
<p>
Transaction isolation is provided for all data manipulation language (DML) statements.
Most data definition language (DDL) statements commit the current transaction.
175
See the <a href="grammar.html">Grammar</a> for details.
176
</p>
177 178 179 180 181 182
<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
183
    Read locks are released immediately after executing the statement, but write locks are kept until the transaction commits.
184
    Higher concurrency is possible when using this level.<br />
185 186
    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>
187 188
</li><li>
<b>Serializable</b><br />
Thomas Mueller's avatar
Thomas Mueller committed
189
    Both read locks and write locks are kept until the transaction commits.
190 191
    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>
192 193
</li><li><b>Read Uncommitted</b><br />
    This level means that transaction isolation is disabled.<br />
194 195
    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>
196 197 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
</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
231
When a lock is released, and multiple connections are waiting for it, one of them is picked at random.
232 233 234 235 236 237 238 239 240 241 242 243
</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
244
<h2 id="mvcc">Multi-Version Concurrency Control (MVCC)</h2>
245 246 247 248
<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,
249
when dropping the table, and when using <code>SELECT ... FOR UPDATE</code>.
250
Connections only 'see' committed data, and own changes. That means, if connection A updates
251 252
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
253 254
(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.
255 256
</p>
<p>
257
To use the MVCC feature, append <code>;MVCC=TRUE</code> to the database URL:
258
</p>
259
<pre>
260 261 262
jdbc:h2:~/test;MVCC=TRUE
</pre>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
263
MVCC is disabled by default. The MVCC feature is not fully tested yet.
264
The limitations of the MVCC mode are: it can not be used at the same time as
265
<code>MULTI_THREADED=TRUE</code>;
266
the complete undo log must fit in memory when using multi-version concurrency
267
(the setting <code>MAX_MEMORY_UNDO</code> has no effect).
Thomas Mueller's avatar
Thomas Mueller committed
268 269
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).
270 271
</p>

Thomas Mueller's avatar
Thomas Mueller committed
272
<h2 id="clustering">Clustering / High Availability</h2>
273 274 275 276 277 278 279 280 281
<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
282 283 284
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.
285 286 287 288 289
</p><p>
To initialize the cluster, use the following steps:
</p>
<ul>
<li>Create a database
290
</li><li>Use the <code>CreateCluster</code> tool to copy the database to
291
    another location and initialize the clustering.
292 293 294 295 296 297 298 299 300 301 302 303
    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>
304
<li>Create two directories: <code>server1, server2</code>.
305 306 307
    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:
308
<pre>
309 310 311 312 313 314 315
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:
316
<pre>
317 318 319 320
java org.h2.tools.Server
    -tcp -tcpPort 9102
    -baseDir server2
</pre>
321
</li><li>Use the <code>CreateCluster</code> tool to initialize clustering.
322 323
    This will automatically create a new, empty database if it does not exist.
    Run the tool on the command line:
324
<pre>
325
java org.h2.tools.CreateCluster
Thomas Mueller's avatar
Thomas Mueller committed
326 327 328 329
    -urlSource jdbc:h2:tcp://localhost:9101/~/test
    -urlTarget jdbc:h2:tcp://localhost:9102/~/test
    -user sa
    -serverList localhost:9101,localhost:9102
330 331 332
</pre>
</li><li>You can now connect to the databases using
an application or the H2 Console using the JDBC URL
333
<code>jdbc:h2:tcp://localhost:9101,localhost:9102/~/test</code>
334 335 336 337 338
</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,
339
and re-run the <code>CreateCluster</code> tool.
340 341
</li></ul>

342 343 344 345 346 347 348 349 350 351 352 353
<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>

354 355 356 357 358
<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
359
executed with care: <code>RANDOM_UUID(), SECURE_RAND(), SESSION_ID(),
360 361
MEMORY_FREE(), MEMORY_USED(), CSVREAD(), CSVWRITE(), RAND()</code> [when not using a seed].
Those functions should not be used directly in modifying statements
362
(for example <code>INSERT, UPDATE, MERGE</code>). However, they can be used
363 364
in read-only statements and the result can then be used for modifying statements.
</p>
Thomas Mueller's avatar
Thomas Mueller committed
365 366 367 368 369
<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>
370

Thomas Mueller's avatar
Thomas Mueller committed
371
<h2 id="two_phase_commit">Two Phase Commit</h2>
372 373 374 375 376 377 378
<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
379
    <code>PREPARE COMMIT transactionName</code>
380 381 382 383
</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
384
    with <code>SELECT * FROM INFORMATION_SCHEMA.IN_DOUBT</code>
385
</li><li>Each transaction in this list must now be committed or rolled back by executing
386 387
    <code>COMMIT TRANSACTION transactionName</code> or
    <code>ROLLBACK TRANSACTION transactionName</code>
388 389 390
</li><li>The database needs to be closed and re-opened to apply the changes
</li></ul>

Thomas Mueller's avatar
Thomas Mueller committed
391
<h2 id="compatibility">Compatibility</h2>
392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408
<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>
409
<code>
410
CROSS, CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP, DISTINCT, EXCEPT, EXISTS, FALSE,
411
FOR, FROM, FULL, GROUP, HAVING, INNER, INTERSECT, IS, JOIN, LIKE, LIMIT, MINUS, NATURAL, NOT, NULL,
Thomas Mueller's avatar
Thomas Mueller committed
412
ON, ORDER, PRIMARY, ROWNUM, SELECT, SYSDATE, SYSTIME, SYSTIMESTAMP, TODAY, TRUE, UNION,
413
UNIQUE, WHERE
414
</code>
415 416
</p><p>
Certain words of this list are keywords because they are functions that can be used without '()' for compatibility,
417
for example <code>CURRENT_TIMESTAMP</code>.
418 419
</p>

Thomas Mueller's avatar
Thomas Mueller committed
420
<h2 id="standards_compliance">Standards Compliance</h2>
421 422 423 424 425 426 427
<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
428
<h2 id="windows_service">Run as Windows Service</h2>
429 430
<p>
Using a native wrapper / adapter, Java applications can be run as a Windows Service.
431 432 433 434
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.
435
The batch files are located in the directory <code>h2/service</code>.
436 437 438 439 440
</p>

<h3>Install the Service</h3>
<p>
The service needs to be registered as a Windows Service first.
441
To do that, double click on <code>1_install_service.bat</code>.
442 443 444 445 446 447
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,
448
or by double clicking on <code>2_start_service.bat</code>.
449 450 451 452 453 454
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.
455
Double clicking on <code>3_start_browser.bat</code> to do that. The
456 457 458 459 460
default port (8082) is hard coded in the batch file.
</p>

<h3>Stop the Service</h3>
<p>
461
To stop the service, double click on <code>4_stop_service.bat</code>.
462 463 464 465 466
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>
467
To uninstall the service, double click on <code>5_uninstall_service.bat</code>.
468 469 470
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
471
<h2 id="odbc_driver">ODBC Driver</h2>
472 473 474 475 476 477 478 479
<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
480
To use the PostgreSQL ODBC driver on 64 bit versions of Windows,
481
first run <code>c:/windows/syswow64/odbcad32.exe</code>.
Thomas Mueller's avatar
Thomas Mueller committed
482 483 484
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>
485 486 487 488 489
</p>

<h3>ODBC Installation</h3>
<p>
First, the ODBC driver must be installed.
490
Any recent PostgreSQL ODBC driver should work, however version 8.2 (<code>psqlodbc-08_02*</code>) or newer is recommended.
491 492 493 494 495 496 497 498
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>
499
<pre>
500 501 502 503 504
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.
505
Use <code>-baseDir</code> to save databases in another directory, for example the user home directory:
506
</p>
507
<pre>
508 509 510 511 512
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>
513
<pre>
Thomas Mueller's avatar
Thomas Mueller committed
514
Server server = Server.createPgServer("-baseDir", "~");
515 516 517 518 519 520
server.start();
...
server.stop();
</pre>
<p>
By default, only connections from localhost are allowed. To allow remote connections, use
521
<code>-pgAllowOthers</code> when starting the server.
522 523 524 525 526
</p>

<h3>ODBC Configuration</h3>
<p>
After installing the driver, a new Data Source must be added. In Windows,
527
run <code>odbcad32.exe</code> to open the Data Source Administrator. Then click on 'Add...'
528
and select the PostgreSQL Unicode driver. Then click 'Finish'.
529 530
You will be able to change the connection properties.
The property column represents the property key in the <code>odbc.ini</code> file
531
(which may be different from the GUI).
532 533 534 535
</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>
536
<tr><td>Database</td><td>~/test;ifexists=true</td>
537
    <td>
538
        The database name. This can include connections settings.<br />
539 540 541 542
        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>
543 544 545
<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>
546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577
<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.
</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
578
<h2 id="microsoft_dot_net">Using H2 in Microsoft .NET</h2>
579 580 581 582 583 584 585 586 587 588 589 590 591 592 593
<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>.
594
</li><li>Copy the <code>h2*.jar</code> file to <code>ikvm/bin</code>
595
</li><li>Run the H2 Console using:
596
    <code>ikvm -jar h2*.jar</code>
597
</li><li>Convert the H2 Console to an <code>.exe</code> file using:
598
    <code>ikvmc -target:winexe h2*.jar</code>.
599
    You may ignore the warnings.
600
</li><li>Create a <code>.dll</code> file using (change the version accordingly):
601
    <code>ikvmc.exe -target:library -version:1.0.69.0 h2*.jar</code>
602 603
</li></ul>
<p>
604 605
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:
606
</p>
607
<pre>
608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626
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
627
<h2 id="acid">ACID</h2>
628 629 630 631
<p>
In the database world, ACID stands for:
</p>
<ul>
Thomas Mueller's avatar
Thomas Mueller committed
632 633 634 635
<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.
636 637 638 639 640 641 642 643 644
</li></ul>

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

<h3>Consistency</h3>
<p>
645 646 647
By default, this database is always in a consistent state.
Referential integrity rules are enforced except when
explicitly disabled.
648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665
</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
666
<h2 id="durability_problems">Durability Problems</h2>
667 668 669 670 671
<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.
672
The test is included in the H2 download, see <code>org.h2.test.poweroff.Test</code>.
673 674 675 676 677 678 679
</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
680
is to use the 'synchronous write' file access mode. In Java, <code>RandomAccessFile</code>
681
supports the modes <code>rws</code> and <code>rwd</code>:
682 683
</p>
<ul>
684 685
<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>
686 687
</ul>
<p>
688
A test (<code>org.h2.test.poweroff.TestWrite</code>) with one of those modes achieves
689
around 50 thousand write operations per second.
690 691 692 693 694 695 696 697
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>
698
Calling <code>fsync</code> flushes the buffers. There are two ways to do that in Java:
699 700
</p>
<ul>
701
<li><code>FileDescriptor.sync()</code>. The documentation says that this forces all system
702
buffers to synchronize with the underlying device.
703
This method is supposed to return after all in-memory modified copies of buffers associated with this file descriptor
704
have been written to the physical medium.
705
</li><li><code>FileChannel.force()</code> (since JDK 1.4). This method is supposed
706
to force any updates to this channel's file to be written to the storage device that contains it.
707 708
</li></ul>
<p>
709
By default, MySQL calls <code>fsync</code> for each commit. When using one of those methods, only around 60 write operations
710
per second can be achieved, which is consistent with the RPM rate of the hard drive used.
711 712
Unfortunately, even when calling <code>FileDescriptor.sync()</code> or
<code>FileChannel.force()</code>,
713
data is not always persisted to the hard drive, because most hard drives do not obey
714
<code>fsync()</code>: see
715
<a href="http://hardware.slashdot.org/article.pl?sid=05/05/13/0529252">Your Hard Drive Lies to You</a>.
716
In Mac OS X, <code>fsync</code> does not flush hard drive buffers. See
717 718 719 720
<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>
721
Trying to flush hard drive buffers is hard, and if you do the performance is very bad.
722 723 724 725 726 727 728
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.
729 730
To change the behavior, use <code>SET WRITE_DELAY</code> and
<code>CHECKPOINT SYNC</code>.
731 732 733 734 735 736 737
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
738
in the package <code>org.h2.test.poweroff</code>.
739
Two computers with network connection are required to run this test.
740 741 742 743 744 745 746 747 748 749 750
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
751
<h2 id="using_recover_tool">Using the Recover Tool</h2>
752
<p>
Thomas Mueller's avatar
Thomas Mueller committed
753 754
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).
755 756
To run the tool, type on the command line:
</p>
757
<pre>
758
java -cp h2*.jar org.h2.tools.Recover
759 760 761
</pre>
<p>
For each database in the current directory, a text file will be created.
762
This file contains raw insert statements (for the data) and data definition (DDL) statements to recreate
763 764 765
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
766 767
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.
768
</p>
769
<p>
Thomas Mueller's avatar
Thomas Mueller committed
770
The <code>Recover</code> tool creates a SQL script from database file. It also processes the transaction log.
771
</p>
772

Thomas Mueller's avatar
Thomas Mueller committed
773
<h2 id="file_locking_protocols">File Locking Protocols</h2>
774
<p>
Thomas Mueller's avatar
Thomas Mueller committed
775 776 777
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.
778
To protect against this problem, whenever a database is opened, a lock file is created
Thomas Mueller's avatar
Thomas Mueller committed
779 780
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.
781 782
</p><p>
In special cases (if the process did not terminate normally, for example because
783
there was a power failure), the lock file is not deleted by the process that created it.
784 785 786 787 788 789 790
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
791 792
<p>
The file locking protocols have the following limitation: if a shared file system is used,
793
and the machine with the lock owner is sent to sleep (standby or hibernate),
Thomas Mueller's avatar
Thomas Mueller committed
794 795 796 797 798
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>
799 800 801 802 803 804

<h3>File Locking Method 'File'</h3>
<p>
The default method for database file locking is the 'File Method'. The algorithm is:
</p>
<ul>
805
<li>If the lock file does not exist, it is created (using the atomic operation
806
<code>File.createNewFile</code>).
807
Then, the process waits a little bit (20 ms) and checks the file again. If the file was changed
808
during this time, the operation is aborted. This protects against a race condition
809
when one process deletes the lock file just after another one create it, and a third process creates
810 811 812 813 814 815 816 817 818 819 820
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>
821
If the lock file exists and was recently modified, the process waits for some time (up to two seconds).
822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842
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.
843
To use it, append <code>;FILE_LOCK=SOCKET</code> to the database URL.
844 845 846 847 848 849 850 851 852 853 854 855
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
856
died (for example due to a power failure, or abnormal termination of the virtual machine),
857 858 859 860 861 862 863 864 865
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>

866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881
<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
882
<h2 id="sql_injection">Protection against SQL Injection</h2>
883 884 885 886 887 888
<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>
889
<pre>
890 891 892 893 894 895
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
896
such as (in this example) this password: <code>' OR ''='</code>.
897
In this case the statement becomes:
898
</p>
899
<pre>
900 901 902 903
SELECT * FROM USERS WHERE PASSWORD='' OR ''='';
</pre>
<p>
Which is always true no matter what the password stored in the database is.
904
For more information about SQL Injection, see <a href="#glossary_links">Glossary and Links</a>.
905 906 907 908 909
</p>

<h3>Disabling Literals</h3>
<p>
SQL Injection is not possible if user input is not directly embedded in SQL statements.
910
A simple solution for the problem above is to use a prepared statement:
911
</p>
912
<pre>
913 914 915 916 917 918 919 920 921 922
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>
923
<pre>
924 925 926 927
SET ALLOW_LITERALS NONE;
</pre>
<p>
Afterwards, SQL statements with text and number literals are not allowed any more.
928 929
That means, SQL statement of the form <code>WHERE NAME='abc'</code>
or <code>WHERE CustomerId=10</code> will fail.
930
It is still possible to use prepared statements and parameters as described above. Also, it is still possible to generate
931 932
SQL statements dynamically, and use the Statement API, as long as the SQL statements
do not include literals.
933
There is also a second mode where number literals are allowed:
934 935
<code>SET ALLOW_LITERALS NUMBERS</code>.
To allow all literals, execute <code>SET ALLOW_LITERALS ALL</code>
936
(this is the default setting). Literals can only be enabled or disabled by an administrator.
937 938 939 940 941
</p>

<h3>Using Constants</h3>
<p>
Disabling literals also means disabling hard-coded 'constant' literals. This database supports
942
defining constants using the <code>CREATE CONSTANT</code> command.
943
Constants can be defined only
944 945 946
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>
947
<pre>
948 949 950 951 952 953 954 955 956 957 958 959 960
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>
961
It is not required to create a constant for the number 0 as there is already a built-in function <code>ZERO()</code>:
962
</p>
963
<pre>
964 965 966
SELECT * FROM USERS WHERE LENGTH(PASSWORD)=ZERO();
</pre>

Thomas Mueller's avatar
Thomas Mueller committed
967
<h2 id="remote_access">Protection against Remote Access</h2>
968
<p>
969
By default this database does not allow connections from other machines when starting the H2 Console,
970
the TCP server, or the PG server. Remote access can be enabled using the command line
971
options <code>-webAllowOthers, -tcpAllowOthers, -pgAllowOthers</code>.
972
If you enable remote access, please also consider using the options
973
<code>-baseDir, -ifExists</code>, so that remote
Thomas Mueller's avatar
Thomas Mueller committed
974
users can not create new databases or access existing databases with weak passwords.
975 976
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.
977 978
</p>

Thomas Mueller's avatar
Thomas Mueller committed
979
<h2 id="restricting_classes">Restricting Class Loading and Usage</h2>
980 981
<p>
By default there is no restriction on loading classes and executing Java code for admins.
982
That means an admin may call system functions such as
983
<code>System.setProperty</code> by executing:
984
</p>
985
<pre>
986 987 988 989 990 991 992
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,
993
the list of allowed classes can be set in the system property
994
<code>h2.allowedClasses</code>
995
in the form of a comma separated list of classes or patterns (items ending with <code>*</code>).
996 997
By default all classes are allowed. Example:
</p>
998
<pre>
999 1000 1001 1002 1003 1004 1005 1006
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
1007
<h2 id="security_protocols">Security Protocols</h2>
1008 1009 1010 1011 1012 1013 1014 1015 1016
<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
1017
user name, @, and password are hashed using SHA-256, and this hash value
1018
is transmitted to the database.
1019
This step does not protect against an attacker that re-uses the value if he is able to listen to the
1020 1021 1022 1023 1024 1025 1026 1027
(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
1028 1029 1030
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.
1031 1032 1033 1034
</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
1035
user-password hash value with the stored salt value and calculates the
1036 1037 1038 1039 1040 1041
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.
1042 1043
If the data is protected by storing it on another computer and only accessible remotely,
then the iteration count is not required at all.
1044 1045 1046 1047 1048 1049 1050 1051 1052
</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
(XTEA is about twice as fast as AES) and to have an alternative algorithm if
AES is suddenly broken.
</p><p>
1053 1054
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
1055 1056 1057
transmitted to the server.
</p><p>
When a new database file is created, a new cryptographically secure
1058
random salt value is generated. The size of the salt is 64 bits.
1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069
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
1070
first, the IV is calculated by encrypting the block number with the IV key (using the same
1071 1072 1073 1074 1075 1076
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>
1077 1078
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
1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090
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>

1091
<h3>Wrong Password / User Name Delay</h3>
1092 1093
<p>
To protect against remote brute force password attacks, the delay after each unsuccessful
1094 1095
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)
1096 1097
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
1098
password, with one exception: after using the wrong password, there is a delay of up to (randomly distributed)
1099 1100 1101 1102
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>
1103 1104 1105 1106 1107
<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>
1108 1109 1110

<h3>HTTPS Connections</h3>
<p>
1111
The web server supports HTTP and HTTPS connections using <code>SSLServerSocket</code>.
1112 1113 1114 1115
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
1116
<h2 id="ssl_tls_connections">SSL/TLS Connections</h2>
1117 1118
<p>
Remote SSL/TLS connections are supported using the Java Secure Socket Extension
1119 1120
(<code>SSLServerSocket, SSLSocket</code>). By default, anonymous SSL is enabled.
The default cipher suite is <code>SSL_DH_anon_WITH_RC4_128_MD5</code>.
1121 1122
</p>
<p>
1123 1124
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.
1125 1126 1127 1128 1129
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>
1130
To disable anonymous SSL, set the system property <code>h2.enableAnonymousSSL</code> to false.
1131 1132
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1133
<h2 id="uuid">Universally Unique Identifiers (UUID)</h2>
1134
<p>
Thomas Mueller's avatar
Thomas Mueller committed
1135
This database supports UUIDs. Also supported is a function to create new UUIDs using
1136 1137 1138 1139 1140
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).
1141
This database supports generating such UUIDs using the built-in function
1142
<code>RANDOM_UUID()</code>.
1143 1144 1145
Here is a small program to estimate the probability of having two identical UUIDs
after generating a number of values:
</p>
1146
<pre>
1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157
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));
        }
    }
1158 1159 1160 1161 1162
}
</pre>
<p>
Some values are:
</p>
1163 1164 1165 1166 1167 1168
<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>
1169 1170
<p>
To help non-mathematicians understand what those numbers mean, here a comparison:
Thomas Mueller's avatar
Thomas Mueller committed
1171
one's annual risk of being hit by a meteorite is estimated to be one chance in 17 billion,
1172 1173 1174
that means the probability is about 0.000'000'000'06.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1175
<h2 id="system_properties">Settings Read from System Properties</h2>
1176 1177
<p>
Some settings of the database can be set on the command line using
1178
<code>-DpropertyName=value</code>. It is usually not required to change those settings manually.
1179 1180 1181
The settings are case sensitive.
Example:
</p>
1182
<pre>
1183 1184 1185 1186
java -Dh2.serverCachedObjects=256 org.h2.tools.Server
</pre>
<p>
The current value of the settings can be read in the table
1187
<code>INFORMATION_SCHEMA.SETTINGS</code>.
1188 1189 1190 1191 1192 1193
</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
1194
<h2 id="server_bind_address">Setting the Server Bind Address</h2>
1195 1196 1197
<p>
Usually server sockets accept connections on any/all local addresses.
This may be a problem on multi-homed hosts.
1198
To bind only to one address, use the system property <code>h2.bindAddress</code>.
1199 1200 1201 1202
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
1203
<h2 id="file_system">Pluggable File System</h2>
1204 1205 1206 1207
<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>
1208
<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
1209
</li><li><code>split:</code> file system that splits files in 1 GB files (stackable with other file systems).
1210 1211
</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
1212 1213
    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
1214 1215
</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).
1216 1217
</li></ul>
<p>
1218 1219
As an example, to use the the <code>nio</code> file system, use the following database URL:
<code>jdbc:h2:nio:~/test</code>.
1220 1221
</p>
<p>
1222 1223
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.
1224 1225
</p>

1226 1227 1228 1229 1230 1231 1232 1233
<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>
1234
The conversion itself is done internally via <code>'script to'</code> and <code>'runscript from'</code>. After the conversion process, the files will be
1235 1236
renamed from
<ul>
1237 1238
<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>
1239 1240 1241 1242
</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>
1243 1244
<li><code>org.h2.upgrade.DbUpgradeNonPageStoreToCurrent.setDeleteOldDb(boolean)</code>
</li><li><code>org.h2.upgrade.DbUpgradeNonPageStoreToCurrent.setScriptInTmpDir(boolean)</code>
1245 1246 1247 1248
</li></ul>
prior opening a database connection.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1249
<h2 id="limits_limitations">Limits and Limitations</h2>
1250 1251 1252 1253
<p>
This database has the following known limitations:
</p>
<ul>
1254
<li>Database file size limits (excluding BLOB and CLOB data):
Thomas Mueller's avatar
Thomas Mueller committed
1255 1256 1257
    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.
1258
</li><li>The maximum file size for FAT or FAT32 file systems is 4 GB. That means when using FAT or FAT32,
1259
the limit is 4 GB for the data. This is the limitation of the file system. The database does provide a
1260
workaround for this problem, it is to use the file name prefix <code>split:</code>. In that case files are split into
1261
files of 1 GB by default. An example database URL is:
1262
<code>jdbc:h2:split:~/test</code>.
Thomas Mueller's avatar
Thomas Mueller committed
1263
</li><li>The maximum number of rows per table is 2'147'483'648.
1264
</li><li>Main memory requirements: The larger the database, the more main memory is required.
Thomas Mueller's avatar
Thomas Mueller committed
1265 1266 1267
    With the default storage mechanism, the minimum main memory required for a 12 GB database is around 240 MB.
    With the page store (experimental), the minimum main memory required is much lower, around 1 MB for each 8 GB database file size.
</li><li>Limit on the complexity of SQL statements.
1268
Statements of the following form will result in a stack overflow exception:
1269
<pre>
1270 1271 1272 1273 1274
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
1275 1276 1277 1278 1279 1280
    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;
1281
    maximum row length, index row length, select row length;
Thomas Mueller's avatar
Thomas Mueller committed
1282
    maximum length of a varchar column, decimal column, literal in a statement.
1283 1284 1285 1286
</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
1287
<h2 id="glossary_links">Glossary and Links</h2>
Thomas Mueller's avatar
Thomas Mueller committed
1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345
<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>
1346 1347
        <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
1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368
            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>
1369 1370 1371
</table>

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