advanced.html 81.6 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-2018 H2 Group. Multiple-Licensed under the MPL 2.0, Version 1.0,
4 5 6 7
and under the Eclipse Public License, Version 1.0
Initial Developer: H2 Group
-->
<html xmlns="http://www.w3.org/1999/xhtml" lang="en" xml:lang="en">
8 9
<head>
<meta http-equiv="Content-Type" content="text/html;charset=utf-8" />
Thomas Mueller's avatar
Thomas Mueller committed
10
<meta name="viewport" content="width=device-width, initial-scale=1" />
11
<title>
12
Advanced
13 14
</title>
<link rel="stylesheet" type="text/css" href="stylesheet.css" />
15 16 17 18 19 20
<!-- [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">
<!-- } -->

21
<h1>Advanced</h1>
22 23 24 25 26 27
<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
28 29
<a href="#spatial_features">
    Spatial Features</a><br />
Thomas Mueller's avatar
Thomas Mueller committed
30 31
<a href="#recursive_queries">
    Recursive Queries</a><br />
Thomas Mueller's avatar
Thomas Mueller committed
32
<a href="#updatable_views">
Thomas Mueller's avatar
Thomas Mueller committed
33
    Updatable Views</a><br />
34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59
<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 />
60 61 62 63
<a href="#passwords">
    Using Passwords</a><br />
<a href="#password_hash">
    Password Hash</a><br />
64 65
<a href="#sql_injection">
    Protection against SQL Injection</a><br />
66 67
<a href="#remote_access">
    Protection against Remote Access</a><br />
68 69 70 71
<a href="#restricting_classes">
    Restricting Class Loading and Usage</a><br />
<a href="#security_protocols">
    Security Protocols</a><br />
72 73
<a href="#tls_connections">
    TLS Connections</a><br />
74 75 76 77 78 79
<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 />
80 81
<a href="#file_system">
    Pluggable File System</a><br />
Thomas Mueller's avatar
Thomas Mueller committed
82 83
<a href="#file_system_split">
    Split File System</a><br />
84 85
<a href="#database_upgrade">
    Database Upgrade</a><br />
86 87
<a href="#java_objects_serialization">
    Java Objects Serialization</a><br />
88 89
<a href="#custom_data_types_handler_api">
    Custom Data Types Handler API</a><br />
Thomas Mueller's avatar
Thomas Mueller committed
90 91
<a href="#limits_limitations">
    Limits and Limitations</a><br />
92 93 94
<a href="#glossary_links">
    Glossary and Links</a><br />

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

97 98
<h3>Statements that Return a Result Set</h3>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
99
The following statements return a result set: <code>SELECT, EXPLAIN, CALL, SCRIPT, SHOW, HELP</code>.
100 101 102
All other statements return an update count.
</p>

103 104 105 106 107 108
<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.
109 110 111
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>.
112 113 114 115
</p>

<h3>Large Result Sets and External Sorting</h3>
<p>
116
For large result set, the result is buffered to disk. The threshold can be defined using the statement
117 118
<code>SET MAX_MEMORY_ROWS</code>.
If <code>ORDER BY</code> is used, the sorting is done using an
119 120 121
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.
122 123
</p>

Thomas Mueller's avatar
Thomas Mueller committed
124
<h2 id="large_objects">Large Objects</h2>
125 126 127 128 129 130

<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.
131 132 133
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>.
134 135
When using the client/server mode, large BLOB and CLOB data is stored in a temporary file
on the client side.
136 137
</p>

138 139
<h3>When to use CLOB/BLOB</h3>
<p>
140
By default, this database stores large LOB (CLOB and BLOB) objects separate from the main table data.
141
Small LOB objects are stored in-place, the threshold can be set using
142
<a href="grammar.html#set_max_length_inplace_lob" class="notranslate" >MAX_LENGTH_INPLACE_LOB</a>,
143 144 145 146 147 148 149 150 151
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>
Thomas Mueller's avatar
Thomas Mueller committed
152 153 154
The following feature is only available for the PageStore storage engine.
For the MVStore engine (the default for H2 version 1.4.x),
append <code>;COMPRESS=TRUE</code> to the database URL instead.
155 156
CLOB and BLOB values can be compressed by using
<a href="grammar.html#set_compress_lob" class="notranslate" >SET COMPRESS_LOB</a>.
157 158 159 160 161
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
162
<h2 id="linked_tables">Linked Tables</h2>
163 164
<p>
This database supports linked tables, which means tables that don't exist in the current database but
165
are just links to another database. To create such a link, use the
166
<code>CREATE LINKED TABLE</code> statement:
167
</p>
168
<pre>
169 170 171 172 173
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.
174 175
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>.
Thomas Mueller's avatar
Thomas Mueller committed
176 177 178 179
The same happens for insert and update statements.
Only simple statements are executed against the target database, that means no joins
(queries that contain joins are converted to simple queries).
Prepared statements are used where possible.
180 181 182 183 184 185
</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
186
is shared. To disable this, set the system property <code>h2.shareLinkedConnections=false</code>.
187 188
</p>
<p>
189 190
The statement <a href="grammar.html#create_linked_table" class="notranslate" >CREATE LINKED TABLE</a>
supports an optional schema name parameter.
191
</p>
192
<p>
Thomas Mueller's avatar
Thomas Mueller committed
193
The following are not supported because they may result in a deadlock:
194 195 196 197
creating a linked table to the same database,
and creating a linked table to another database using the server mode if the other database is open in the same server
(use the embedded mode instead).
</p>
Thomas Mueller's avatar
Thomas Mueller committed
198 199 200 201 202
<p>
Data types that are not supported in H2 are also not supported for linked tables,
for example unsigned data types if the value is outside the range of the signed type.
In such cases, the columns needs to be cast to a supported type.
</p>
203

Thomas Mueller's avatar
Thomas Mueller committed
204 205
<h2 id="updatable_views">Updatable Views</h2>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
206
By default, views are not updatable.
Thomas Mueller's avatar
Thomas Mueller committed
207 208 209
To make a view updatable, use an "instead of" trigger as follows:
</p>
<pre>
Thomas Mueller's avatar
Thomas Mueller committed
210 211 212
CREATE TRIGGER TRIGGER_NAME
INSTEAD OF INSERT, UPDATE, DELETE
ON VIEW_NAME
Thomas Mueller's avatar
Thomas Mueller committed
213 214 215 216 217 218 219
FOR EACH ROW CALL "com.acme.TriggerClassName";
</pre>
<p>
Update the base table(s) within the trigger as required.
For details, see the sample application <code>org.h2.samples.UpdatableView</code>.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
220
<h2 id="transaction_isolation">Transaction Isolation</h2>
221
<p>
Thomas Mueller's avatar
Thomas Mueller committed
222 223
Please note that most data definition language (DDL) statements,
such as "create table", commit the current transaction.
224
See the <a href="grammar.html">Grammar</a> for details.
225
</p>
226
<p>
Thomas Mueller's avatar
Thomas Mueller committed
227 228
Transaction isolation is provided for all data manipulation language (DML) statements.
</p>
Thomas Mueller's avatar
Thomas Mueller committed
229
<p>
230
Please note that with default MVStore storage engine table level locking is not used.
Thomas Mueller's avatar
Thomas Mueller committed
231
Instead, rows are locked for update, and read committed is used in all cases
232
except for explicitly selected read uncommitted transaction isolation level.
Thomas Mueller's avatar
Thomas Mueller committed
233
</p>
Thomas Mueller's avatar
Thomas Mueller committed
234
<p>
235 236 237 238 239
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
240
    Read locks are released immediately after executing the statement, but write locks are kept until the transaction commits.
241
    Higher concurrency is possible when using this level.<br />
242 243
    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>
244 245
</li><li>
<b>Serializable</b><br />
Thomas Mueller's avatar
Thomas Mueller committed
246
    Both read locks and write locks are kept until the transaction commits.
247 248
    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>
249
</li><li><b>Read Uncommitted</b><br />
250 251 252
    This level means that transaction isolation is disabled.
    This level is not supported by PageStore engine if multi-threaded mode is enabled.
    <br />
253 254
    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>
255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289
</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
290
When a lock is released, and multiple connections are waiting for it, one of them is picked at random.
291 292 293 294 295 296 297 298 299 300 301 302
</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
303
<h2 id="mvcc">Multi-Version Concurrency Control (MVCC)</h2>
304 305
<p>
The MVCC feature allows higher concurrency than using (table level or row level) locks.
306 307
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,
308
when dropping the table, and when using <code>SELECT ... FOR UPDATE</code>.
309
Connections only 'see' committed data, and own changes. That means, if connection A updates
310 311
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
312 313
(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.
314 315
</p>
<p>
316 317
This feature is only available with the default MVStore storage engine.
Changing the lock mode with it (<code>LOCK_MODE</code>) has no effect.
318
</p>
Thomas Mueller's avatar
Thomas Mueller committed
319
<p>
320
MVCC is not used when using the PageStore storage engine.
321
</p>
322

Thomas Mueller's avatar
Thomas Mueller committed
323
<h2 id="clustering">Clustering / High Availability</h2>
324 325 326 327 328 329 330 331 332
<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
333 334 335
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.
336 337 338 339 340
</p><p>
To initialize the cluster, use the following steps:
</p>
<ul>
<li>Create a database
341
</li><li>Use the <code>CreateCluster</code> tool to copy the database to
342
    another location and initialize the clustering.
343 344 345 346 347 348 349 350 351 352 353 354
    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>
355
<li>Create two directories: <code>server1, server2</code>.
356 357 358
    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:
359
<pre>
360 361 362 363 364 365 366
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:
367
<pre>
368 369 370 371
java org.h2.tools.Server
    -tcp -tcpPort 9102
    -baseDir server2
</pre>
372
</li><li>Use the <code>CreateCluster</code> tool to initialize clustering.
373 374
    This will automatically create a new, empty database if it does not exist.
    Run the tool on the command line:
375
<pre>
376
java org.h2.tools.CreateCluster
Thomas Mueller's avatar
Thomas Mueller committed
377 378 379 380
    -urlSource jdbc:h2:tcp://localhost:9101/~/test
    -urlTarget jdbc:h2:tcp://localhost:9102/~/test
    -user sa
    -serverList localhost:9101,localhost:9102
381 382 383
</pre>
</li><li>You can now connect to the databases using
an application or the H2 Console using the JDBC URL
384
<code>jdbc:h2:tcp://localhost:9101,localhost:9102/~/test</code>
385 386 387 388 389
</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,
390
and re-run the <code>CreateCluster</code> tool.
391 392
</li></ul>

393 394 395 396 397 398 399 400 401 402 403 404
<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>

Thomas Mueller's avatar
Thomas Mueller committed
405 406 407
<p>
It is also possible to get the list of servers by using Connection.getClientInfo().
</p>
408

Thomas Mueller's avatar
Thomas Mueller committed
409
<p>
Thomas Mueller's avatar
Thomas Mueller committed
410
The property list returned from <code>getClientInfo()</code> contains a <code>numServers</code> property that returns the
411 412
number of servers that are in the connection list. To get the actual servers, <code>getClientInfo()</code> also has
properties <code>server0</code>..<code>serverX</code>, where serverX is the number of servers minus 1.
Thomas Mueller's avatar
Thomas Mueller committed
413
</p>
414

Thomas Mueller's avatar
Thomas Mueller committed
415
<p>
Thomas Mueller's avatar
Thomas Mueller committed
416 417
Example: To get the 2nd server in the connection list one uses <code>getClientInfo('server1')</code>.
<b>Note:</b> The <code>serverX</code> property only returns IP addresses and ports and not hostnames.
Thomas Mueller's avatar
Thomas Mueller committed
418
</p>
419

420 421 422 423 424
<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
425
executed with care: <code>UUID(), RANDOM_UUID(), SECURE_RAND(), SESSION_ID(),
426 427
MEMORY_FREE(), MEMORY_USED(), CSVREAD(), CSVWRITE(), RAND()</code> [when not using a seed].
Those functions should not be used directly in modifying statements
428
(for example <code>INSERT, UPDATE, MERGE</code>). However, they can be used
429
in read-only statements and the result can then be used for modifying statements.
Thomas Mueller's avatar
Thomas Mueller committed
430 431
Using auto-increment and identity columns is currently not supported.
Instead, sequence values need to be manually requested and then used to insert data (using two statements).
432
</p>
Thomas Mueller's avatar
Thomas Mueller committed
433 434 435 436 437
<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>
438 439 440 441
<p>
The SQL statement <code>SET AUTOCOMMIT FALSE</code> is not supported in the cluster mode.
To disable autocommit, the method <code>Connection.setAutoCommit(false)</code> needs to be called.
</p>
Thomas Mueller's avatar
Thomas Mueller committed
442 443 444 445 446
<p>
It is possible that a transaction from one connection overtakes a transaction from a different connection.
Depending on the operations, this might result in different results, for example when
conditionally incrementing a value in a row.
</p>
447

Thomas Mueller's avatar
Thomas Mueller committed
448
<h2 id="two_phase_commit">Two Phase Commit</h2>
449 450 451 452 453 454 455
<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
456
    <code>PREPARE COMMIT transactionName</code>
457 458 459 460
</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
461
    with <code>SELECT * FROM INFORMATION_SCHEMA.IN_DOUBT</code>
462
</li><li>Each transaction in this list must now be committed or rolled back by executing
463 464
    <code>COMMIT TRANSACTION transactionName</code> or
    <code>ROLLBACK TRANSACTION transactionName</code>
465 466 467
</li><li>The database needs to be closed and re-opened to apply the changes
</li></ul>

Thomas Mueller's avatar
Thomas Mueller committed
468
<h2 id="compatibility">Compatibility</h2>
469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485
<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>
486
<code>
487
ALL, CHECK, CONSTRAINT, CROSS, CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP, DISTINCT, EXCEPT,
488
EXISTS, FALSE, FETCH, FOR, FOREIGN, FROM, FULL, GROUP, HAVING, INNER, INTERSECT, INTERSECTS,
489 490 491
IS, JOIN, LIKE, LIMIT, LOCALTIME, LOCALTIMESTAMP, MINUS, NATURAL, NOT, NULL, OFFSET, ON, ORDER,
PRIMARY, ROWNUM, SELECT, SYSDATE, SYSTIME, SYSTIMESTAMP, TODAY, TOP, TRUE, UNION, UNIQUE, WHERE,
WITH
492
</code>
493 494
</p><p>
Certain words of this list are keywords because they are functions that can be used without '()' for compatibility,
495
for example <code>CURRENT_TIMESTAMP</code>.
496 497
</p>

Thomas Mueller's avatar
Thomas Mueller committed
498
<h2 id="standards_compliance">Standards Compliance</h2>
499 500 501 502 503 504 505
<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
506 507 508 509 510
<h3>Supported Character Sets, Character Encoding, and Unicode</h3>
<p>
H2 internally uses Unicode, and supports all character encoding systems and character sets supported by the virtual machine you use.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
511
<h2 id="windows_service">Run as Windows Service</h2>
512 513
<p>
Using a native wrapper / adapter, Java applications can be run as a Windows Service.
514
There are various tools available to do that. The Java Service Wrapper from
515
<a href="https://wrapper.tanukisoftware.org">Tanuki Software, Inc.</a>
516 517
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.
518
The batch files are located in the directory <code>h2/service</code>.
519
</p>
Thomas Mueller's avatar
Thomas Mueller committed
520
<p>
521
The service wrapper bundled with H2 is a 32-bit version.
Thomas Mueller's avatar
Thomas Mueller committed
522
To use a 64-bit version of Windows (x64), you need to use a 64-bit version of the wrapper,
523
for example the one from
524
<a href="https://www.krenger.ch/blog/java-service-wrapper-3-5-14-for-windows-x64/">
Thomas Mueller's avatar
Thomas Mueller committed
525 526 527
Simon Krenger</a>.
</p>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
528 529
When running the database as a service, absolute path should be used.
Using <code>~</code> in the database URL is problematic in this case,
Thomas Mueller's avatar
Thomas Mueller committed
530
because it means to use the home directory of the current user.
Thomas Mueller's avatar
Thomas Mueller committed
531 532 533
The service might run without or with the wrong user, so that
the database files might end up in an unexpected place.
</p>
534 535 536 537

<h3>Install the Service</h3>
<p>
The service needs to be registered as a Windows Service first.
538
To do that, double click on <code>1_install_service.bat</code>.
539 540 541 542 543 544
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,
545
or by double clicking on <code>2_start_service.bat</code>.
546 547 548 549 550 551
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.
552
Double clicking on <code>3_start_browser.bat</code> to do that. The
553 554 555 556 557
default port (8082) is hard coded in the batch file.
</p>

<h3>Stop the Service</h3>
<p>
558
To stop the service, double click on <code>4_stop_service.bat</code>.
559 560 561 562 563
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>
564
To uninstall the service, double click on <code>5_uninstall_service.bat</code>.
565 566 567
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
568 569 570 571 572
<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
573 574
(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
575 576
</p>

Thomas Mueller's avatar
Thomas Mueller committed
577
<h2 id="odbc_driver">ODBC Driver</h2>
578 579 580 581 582 583 584 585
<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
586
To use the PostgreSQL ODBC driver on 64 bit versions of Windows,
587
first run <code>c:/windows/syswow64/odbcad32.exe</code>.
Thomas Mueller's avatar
Thomas Mueller committed
588 589
At this point you set up your DSN just like you would on any other system.
See also:
590
<a href="https://www.postgresql.org/message-id/dg76q0$khn$1@sea.gmane.org">Re: ODBC Driver on Windows 64 bit</a>
591 592 593 594 595
</p>

<h3>ODBC Installation</h3>
<p>
First, the ODBC driver must be installed.
596
Any recent PostgreSQL ODBC driver should work, however version 8.2 (<code>psqlodbc-08_02*</code>) or newer is recommended.
597
The Windows version of the PostgreSQL ODBC driver is available at
598
<a href="https://www.postgresql.org/ftp/odbc/versions/msi/">https://www.postgresql.org/ftp/odbc/versions/msi/</a>.
599 600 601 602 603 604
</p>

<h3>Starting the Server</h3>
<p>
After installing the ODBC driver, start the H2 Server using the command line:
</p>
605
<pre>
606 607 608 609 610
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.
611
Use <code>-baseDir</code> to save databases in another directory, for example the user home directory:
612
</p>
613
<pre>
614 615 616 617 618
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>
619
<pre>
Thomas Mueller's avatar
Thomas Mueller committed
620
Server server = Server.createPgServer("-baseDir", "~");
621 622 623 624 625 626
server.start();
...
server.stop();
</pre>
<p>
By default, only connections from localhost are allowed. To allow remote connections, use
627
<code>-pgAllowOthers</code> when starting the server.
628
</p>
Thomas Mueller's avatar
Thomas Mueller committed
629 630 631 632 633 634 635 636 637
<p>
To map an ODBC database name to a different JDBC database name,
use the option <code>-key</code> when starting the server.
Please note only one mapping is allowed. The following will map the ODBC database named
<code>TEST</code> to the database URL <code>jdbc:h2:~/data/test;cipher=aes</code>:
</p>
<pre>
java org.h2.tools.Server -pg -key TEST "~/data/test;cipher=aes"
</pre>
638 639 640 641

<h3>ODBC Configuration</h3>
<p>
After installing the driver, a new Data Source must be added. In Windows,
642
run <code>odbcad32.exe</code> to open the Data Source Administrator. Then click on 'Add...'
643
and select the PostgreSQL Unicode driver. Then click 'Finish'.
644 645
You will be able to change the connection properties.
The property column represents the property key in the <code>odbc.ini</code> file
646
(which may be different from the GUI).
647
</p>
648
<table class="main">
649 650
<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>
651
<tr><td>Database</td><td>~/test;ifexists=true</td>
652
    <td>
653 654 655
        The database name. This can include connections settings.
        By default, the database is stored in the current working directory
        where the Server is started except when the -baseDir setting is used.
656 657
        The name must be at least 3 characters.
    </td></tr>
658 659 660
<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>
661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676
<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
677
Also, H2 does not provide index meta over ODBC.
678 679 680 681 682 683 684 685 686 687 688 689 690 691 692
</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
693 694 695 696
<p>
The first connection that opens a database using the PostgreSQL server needs to be an administrator user.
Subsequent connections don't need to be opened by an administrator.
</p>
697

Thomas Mueller's avatar
Thomas Mueller committed
698 699 700 701 702 703
<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
704
<h2 id="microsoft_dot_net">Using H2 in Microsoft .NET</h2>
705 706 707 708 709 710 711 712
<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
713
<a href="https://code.google.com/archive/p/h2sharp/">H2Sharp</a>.
714 715 716
</p>

<h3>Using the JDBC API on .NET</h3>
717
<ul><li>Install the .NET Framework from <a href="https://www.microsoft.com">Microsoft</a>.
718 719
    Mono has not yet been tested.
</li><li>Install <a href="http://www.ikvm.net">IKVM.NET</a>.
720
</li><li>Copy the <code>h2*.jar</code> file to <code>ikvm/bin</code>
721
</li><li>Run the H2 Console using:
722
    <code>ikvm -jar h2*.jar</code>
723
</li><li>Convert the H2 Console to an <code>.exe</code> file using:
724
    <code>ikvmc -target:winexe h2*.jar</code>.
725
    You may ignore the warnings.
726
</li><li>Create a <code>.dll</code> file using (change the version accordingly):
727
    <code>ikvmc.exe -target:library -version:1.0.69.0 h2*.jar</code>
728 729
</li></ul>
<p>
730 731
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:
732
</p>
733
<pre>
734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752
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
753
<h2 id="acid">ACID</h2>
754 755 756 757
<p>
In the database world, ACID stands for:
</p>
<ul>
Thomas Mueller's avatar
Thomas Mueller committed
758 759 760 761
<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.
762 763 764 765 766 767 768 769 770
</li></ul>

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

<h3>Consistency</h3>
<p>
771 772 773
By default, this database is always in a consistent state.
Referential integrity rules are enforced except when
explicitly disabled.
774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791
</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
792
<h2 id="durability_problems">Durability Problems</h2>
793 794 795 796 797
<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.
798
The test is included in the H2 download, see <code>org.h2.test.poweroff.Test</code>.
799 800 801 802 803 804 805
</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
806
is to use the 'synchronous write' file access mode. In Java, <code>RandomAccessFile</code>
807
supports the modes <code>rws</code> and <code>rwd</code>:
808 809
</p>
<ul>
810 811
<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>
812 813
</ul>
<p>
814
A test (<code>org.h2.test.poweroff.TestWrite</code>) with one of those modes achieves
815
around 50 thousand write operations per second.
816 817 818 819 820 821 822 823
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>
824
Calling <code>fsync</code> flushes the buffers. There are two ways to do that in Java:
825 826
</p>
<ul>
827
<li><code>FileDescriptor.sync()</code>. The documentation says that this forces all system
828
buffers to synchronize with the underlying device.
829
This method is supposed to return after all in-memory modified copies of buffers associated with this file descriptor
830
have been written to the physical medium.
831
</li><li><code>FileChannel.force()</code>. This method is supposed
832
to force any updates to this channel's file to be written to the storage device that contains it.
833 834
</li></ul>
<p>
835
By default, MySQL calls <code>fsync</code> for each commit. When using one of those methods, only around 60 write operations
836
per second can be achieved, which is consistent with the RPM rate of the hard drive used.
837 838
Unfortunately, even when calling <code>FileDescriptor.sync()</code> or
<code>FileChannel.force()</code>,
839
data is not always persisted to the hard drive, because most hard drives do not obey
840
<code>fsync()</code>: see
841
<a href="https://hardware.slashdot.org/story/05/05/13/0529252/your-hard-drive-lies-to-you">Your Hard Drive Lies to You</a>.
842
In Mac OS X, <code>fsync</code> does not flush hard drive buffers. See
843
<a href="https://lists.apple.com/archives/darwin-dev/2005/Feb/msg00072.html">Bad fsync?</a>.
844 845 846
So the situation is confusing, and tests prove there is a problem.
</p>
<p>
847
Trying to flush hard drive buffers is hard, and if you do the performance is very bad.
848 849 850 851 852 853 854
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.
855 856
To change the behavior, use <code>SET WRITE_DELAY</code> and
<code>CHECKPOINT SYNC</code>.
857 858 859 860 861 862 863
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
864
in the package <code>org.h2.test.poweroff</code>.
865
Two computers with network connection are required to run this test.
866 867 868 869 870 871 872 873 874 875 876
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
877
<h2 id="using_recover_tool">Using the Recover Tool</h2>
878
<p>
Thomas Mueller's avatar
Thomas Mueller committed
879 880
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).
881 882
To run the tool, type on the command line:
</p>
883
<pre>
884
java -cp h2*.jar org.h2.tools.Recover
885 886 887
</pre>
<p>
For each database in the current directory, a text file will be created.
888
This file contains raw insert statements (for the data) and data definition (DDL) statements to recreate
889 890 891
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
892 893
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.
894
</p>
895
<p>
Thomas Mueller's avatar
Thomas Mueller committed
896
The <code>Recover</code> tool creates a SQL script from database file. It also processes the transaction log.
897
</p>
Thomas Mueller's avatar
Thomas Mueller committed
898
<p>
Thomas Mueller's avatar
Thomas Mueller committed
899
To verify the database can recover at any time, append <code>;RECOVER_TEST=64</code>
Thomas Mueller's avatar
Thomas Mueller committed
900 901 902 903
to the database URL in your test environment. This will simulate an application crash after each 64 writes to the database file.
A log file named <code>databaseName.h2.db.log</code> is created that lists the operations.
The recovery is tested using an in-memory file system, that means it may require a larger heap setting.
</p>
904

Thomas Mueller's avatar
Thomas Mueller committed
905
<h2 id="file_locking_protocols">File Locking Protocols</h2>
906
<p>
Thomas Mueller's avatar
Thomas Mueller committed
907 908 909
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.
910
To protect against this problem, whenever a database is opened, a lock file is created
Thomas Mueller's avatar
Thomas Mueller committed
911 912
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.
913 914
</p><p>
In special cases (if the process did not terminate normally, for example because
915
there was a power failure), the lock file is not deleted by the process that created it.
916 917 918 919 920 921 922
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
923
<p>
Thomas Mueller's avatar
Thomas Mueller committed
924
The file locking protocols (except the file locking method 'FS')
Thomas Mueller's avatar
Thomas Mueller committed
925
have the following limitation: if a shared file system is used,
926
and the machine with the lock owner is sent to sleep (standby or hibernate),
Thomas Mueller's avatar
Thomas Mueller committed
927 928 929 930 931
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>
932 933 934

<h3>File Locking Method 'File'</h3>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
935
The default method for database file locking for version 1.3 and older is the 'File Method'.
Thomas Mueller's avatar
Thomas Mueller committed
936
The algorithm is:
937 938
</p>
<ul>
939
<li>If the lock file does not exist, it is created (using the atomic operation
940
<code>File.createNewFile</code>).
941
Then, the process waits a little bit (20 ms) and checks the file again. If the file was changed
942
during this time, the operation is aborted. This protects against a race condition
943
when one process deletes the lock file just after another one create it, and a third process creates
944 945 946 947 948 949 950 951 952 953 954
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>
955
If the lock file exists and was recently modified, the process waits for some time (up to two seconds).
956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976
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.
977
To use it, append <code>;FILE_LOCK=SOCKET</code> to the database URL.
978 979 980 981 982 983 984 985 986 987 988 989
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
990
died (for example due to a power failure, or abnormal termination of the virtual machine),
991 992 993 994 995 996 997 998 999
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>

Thomas Mueller's avatar
Thomas Mueller committed
1000 1001
<h3>File Locking Method 'FS'</h3>
<p>
noelgrandin's avatar
noelgrandin committed
1002
This is the default mode for version 1.4 and newer.
Thomas Mueller's avatar
Thomas Mueller committed
1003
This database file locking mechanism uses native file system lock on the database file.
Thomas Mueller's avatar
Thomas Mueller committed
1004
No *.lock.db file is created in this case, and no background thread is started.
Thomas Mueller's avatar
Thomas Mueller committed
1005
This mechanism may not work on all systems as expected.
Thomas Mueller's avatar
Thomas Mueller committed
1006
Some systems allow to lock the same file multiple times within the same virtual machine,
Thomas Mueller's avatar
Thomas Mueller committed
1007 1008 1009 1010 1011 1012 1013 1014 1015 1016
and on some system native file locking is not supported or files are not unlocked after a power failure.
</p>
<p>
To enable this feature, append <code>;FILE_LOCK=FS</code> to the database URL.
</p>
<p>
This feature is relatively new. When using it for production, please ensure
your system does in fact lock files as expected.
</p>

1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093
<h2 id="passwords">Using Passwords</h2>

<h3>Using Secure Passwords</h3>
<p>
Remember that weak passwords can be broken regardless of the encryption and security protocols.
Don't use passwords that can be found in a dictionary. Appending numbers does not make passwords
secure. A way to create good passwords that can be remembered is: take the first
letters of a sentence, use upper and lower case characters, and creatively include special characters
(but it's more important to use a long password than to use special characters).
Example:
</p><p>
<code>i'sE2rtPiUKtT</code> from the sentence <code>it's easy to remember this password if you know the trick</code>.
</p>

<h3>Passwords: Using Char Arrays instead of Strings</h3>
<p>
Java strings are immutable objects and cannot be safely 'destroyed' by the application.
After creating a string, it will remain in the main memory of the computer at least
until it is garbage collected. The garbage collection cannot be controlled by the application,
and even if it is garbage collected the data may still remain in memory.
It might also be possible that the part of memory containing the password
is swapped to disk (if not enough main memory is available), which is
a problem if the attacker has access to the swap file of the operating system.
</p><p>
It is a good idea to use char arrays instead of strings for passwords.
Char arrays can be cleared (filled with zeros) after use, and therefore the
password will not be stored in the swap file.
</p><p>
This database supports using char arrays instead of string to pass user and file passwords.
The following code can be used to do that:
</p>
<pre>
import java.sql.*;
import java.util.*;
public class Test {
    public static void main(String[] args) throws Exception {
        String url = "jdbc:h2:~/test";
        Properties prop = new Properties();
        prop.setProperty("user", "sa");
        System.out.print("Password?");
        char[] password = System.console().readPassword();
        prop.put("password", password);
        Connection conn = null;
        try {
            conn = DriverManager.getConnection(url, prop);
        } finally {
            Arrays.fill(password, (char) 0);
        }
        conn.close();
    }
}
</pre>
<p>
When using Swing, use <code>javax.swing.JPasswordField</code>.
</p>

<h3>Passing the User Name and/or Password in the URL</h3>
<p>
Instead of passing the user name as a separate parameter as in
<code>
Connection conn = DriverManager.
    getConnection("jdbc:h2:~/test", "sa", "123");
</code>
the user name (and/or password) can be supplied in the URL itself:
<code>
Connection conn = DriverManager.
    getConnection("jdbc:h2:~/test;USER=sa;PASSWORD=123");
</code>
The settings in the URL override the settings passed as a separate parameter.
</p>

<h2 id="password_hash">Password Hash</h2>
<p>
Sometimes the database password needs to be stored in a configuration file
(for example in the <code>web.xml</code> file).
In addition to connecting with the plain text password,
this database supports connecting with the password hash.
Thomas Mueller's avatar
Thomas Mueller committed
1094
This means that only the hash of the password (and not the plain text password)
1095
needs to be stored in the configuration file.
Thomas Mueller's avatar
Thomas Mueller committed
1096 1097
This will only protect others from reading or re-constructing the plain text password
(even if they have access to the configuration file);
1098 1099 1100 1101 1102 1103 1104 1105 1106
it does not protect others from accessing the database using the password hash.
</p>
<p>
To connect using the password hash instead of plain text password, append
<code>;PASSWORD_HASH=TRUE</code> to the database URL, and replace
the password with the password hash. To calculate the password hash from a plain text password,
run the following command within the H2 Console tool:
<code>@password_hash &lt;upperCaseUserName&gt; &lt;password&gt;</code>.
As an example, if the user name is <code>sa</code> and the password is
Thomas Mueller's avatar
Thomas Mueller committed
1107
<code>test</code>, run the command
1108 1109 1110 1111 1112 1113 1114
<code>@password_hash SA test</code>.
Then use the resulting password hash as you would use the plain text password.
When using an encrypted database, then the user password and file password
need to be hashed separately. To calculate the hash of the file password, run:
<code>@password_hash file &lt;filePassword&gt;</code>.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1115
<h2 id="sql_injection">Protection against SQL Injection</h2>
1116 1117 1118 1119 1120 1121
<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>
1122
<pre>
1123 1124 1125 1126 1127 1128
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
1129
such as (in this example) this password: <code>' OR ''='</code>.
1130
In this case the statement becomes:
1131
</p>
1132
<pre>
1133 1134 1135 1136
SELECT * FROM USERS WHERE PASSWORD='' OR ''='';
</pre>
<p>
Which is always true no matter what the password stored in the database is.
1137
For more information about SQL Injection, see <a href="#glossary_links">Glossary and Links</a>.
1138 1139 1140 1141 1142
</p>

<h3>Disabling Literals</h3>
<p>
SQL Injection is not possible if user input is not directly embedded in SQL statements.
1143
A simple solution for the problem above is to use a prepared statement:
1144
</p>
1145
<pre>
1146 1147 1148 1149 1150 1151 1152 1153 1154 1155
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>
1156
<pre>
1157 1158 1159 1160
SET ALLOW_LITERALS NONE;
</pre>
<p>
Afterwards, SQL statements with text and number literals are not allowed any more.
1161 1162
That means, SQL statement of the form <code>WHERE NAME='abc'</code>
or <code>WHERE CustomerId=10</code> will fail.
1163
It is still possible to use prepared statements and parameters as described above. Also, it is still possible to generate
1164 1165
SQL statements dynamically, and use the Statement API, as long as the SQL statements
do not include literals.
1166
There is also a second mode where number literals are allowed:
1167 1168
<code>SET ALLOW_LITERALS NUMBERS</code>.
To allow all literals, execute <code>SET ALLOW_LITERALS ALL</code>
1169
(this is the default setting). Literals can only be enabled or disabled by an administrator.
1170 1171 1172 1173 1174
</p>

<h3>Using Constants</h3>
<p>
Disabling literals also means disabling hard-coded 'constant' literals. This database supports
1175
defining constants using the <code>CREATE CONSTANT</code> command.
1176
Constants can be defined only
1177 1178 1179
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>
1180
<pre>
1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193
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>
1194
It is not required to create a constant for the number 0 as there is already a built-in function <code>ZERO()</code>:
1195
</p>
1196
<pre>
1197 1198 1199
SELECT * FROM USERS WHERE LENGTH(PASSWORD)=ZERO();
</pre>

Thomas Mueller's avatar
Thomas Mueller committed
1200
<h2 id="remote_access">Protection against Remote Access</h2>
1201
<p>
1202
By default this database does not allow connections from other machines when starting the H2 Console,
1203
the TCP server, or the PG server. Remote access can be enabled using the command line
1204
options <code>-webAllowOthers, -tcpAllowOthers, -pgAllowOthers</code>.
Thomas Mueller's avatar
Thomas Mueller committed
1205 1206 1207 1208 1209 1210 1211
</p>
<p>
If you enable remote access using
<code>-tcpAllowOthers</code> or <code>-pgAllowOthers</code>,
please also consider using the options <code>-baseDir, -ifExists</code>,
so that remote users can not create new databases
or access existing databases with weak passwords.
1212 1213
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.
1214
</p>
Thomas Mueller's avatar
Thomas Mueller committed
1215 1216
<p>
If you enable remote access using <code>-webAllowOthers</code>,
1217
please ensure the web server can only be accessed from trusted networks.
Thomas Mueller's avatar
Thomas Mueller committed
1218 1219 1220 1221 1222
The options <code>-baseDir, -ifExists</code> don't protect
access to the tools section, prevent remote shutdown of the web server,
changes to the preferences, the saved connection settings,
or access to other databases accessible from the system.
</p>
1223

Thomas Mueller's avatar
Thomas Mueller committed
1224
<h2 id="restricting_classes">Restricting Class Loading and Usage</h2>
1225 1226
<p>
By default there is no restriction on loading classes and executing Java code for admins.
1227
That means an admin may call system functions such as
1228
<code>System.setProperty</code> by executing:
1229
</p>
1230
<pre>
1231 1232 1233 1234 1235 1236 1237
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,
1238
the list of allowed classes can be set in the system property
1239
<code>h2.allowedClasses</code>
1240
in the form of a comma separated list of classes or patterns (items ending with <code>*</code>).
1241 1242
By default all classes are allowed. Example:
</p>
1243
<pre>
1244 1245 1246 1247 1248 1249 1250 1251
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
1252
<h2 id="security_protocols">Security Protocols</h2>
1253 1254 1255 1256 1257 1258 1259 1260 1261
<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
1262
user name, @, and password are hashed using SHA-256, and this hash value
1263
is transmitted to the database.
1264
This step does not protect against an attacker that re-uses the value if he is able to listen to the
1265 1266 1267 1268 1269 1270 1271 1272
(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
1273 1274 1275
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.
1276 1277 1278 1279
</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
1280
user-password hash value with the stored salt value and calculates the
1281 1282 1283 1284 1285 1286
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.
1287 1288
If the data is protected by storing it on another computer and only accessible remotely,
then the iteration count is not required at all.
1289 1290 1291 1292
</p>

<h3>File Encryption</h3>
<p>
1293
The database files can be encrypted using the AES-128 algorithm.
1294
</p><p>
1295 1296
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
1297 1298 1299
transmitted to the server.
</p><p>
When a new database file is created, a new cryptographically secure
1300
random salt value is generated. The size of the salt is 64 bits.
1301 1302 1303 1304
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>
Thomas Mueller's avatar
Thomas Mueller committed
1305
The resulting hash value is used as the key for the block cipher algorithm.
1306
Then, an initialization vector (IV) key
1307 1308 1309 1310 1311
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
1312
first, the IV is calculated by encrypting the block number with the IV key (using the same
1313
block cipher algorithm). This IV is combined with the plain text using XOR. The resulting data is
1314
encrypted using the AES-128 algorithm.
1315 1316 1317 1318
</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>
1319 1320
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
1321 1322 1323 1324 1325 1326 1327 1328 1329
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,
1330
database operations take about 2.5 times longer using AES (embedded mode).
1331 1332
</p>

1333
<h3>Wrong Password / User Name Delay</h3>
1334 1335
<p>
To protect against remote brute force password attacks, the delay after each unsuccessful
1336 1337
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)
1338 1339
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
1340
password, with one exception: after using the wrong password, there is a delay of up to (randomly distributed)
1341 1342 1343 1344
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>
1345 1346 1347 1348 1349
<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>
1350 1351 1352

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

1358
<h2 id="tls_connections">TLS Connections</h2>
1359
<p>
1360 1361
Remote TLS connections are supported using the Java Secure Socket Extension
(<code>SSLServerSocket, SSLSocket</code>). By default, anonymous TLS is enabled.
1362 1363
</p>
<p>
1364 1365
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.
1366
See also <a href="https://docs.oracle.com/javase/7/docs/technotes/guides/security/jsse/JSSERefGuide.html#CustomizingStores">
1367 1368 1369 1370
Customizing the Default Key and Trust Stores, Store Types, and Store Passwords</a>
for more information.
</p>
<p>
1371
To disable anonymous TLS, set the system property <code>h2.enableAnonymousTLS</code> to false.
1372 1373
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1374
<h2 id="uuid">Universally Unique Identifiers (UUID)</h2>
1375
<p>
Thomas Mueller's avatar
Thomas Mueller committed
1376
This database supports UUIDs. Also supported is a function to create new UUIDs using
1377 1378 1379 1380 1381
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).
1382
This database supports generating such UUIDs using the built-in function
1383
<code>RANDOM_UUID()</code> or <code>UUID()</code>.
1384 1385 1386
Here is a small program to estimate the probability of having two identical UUIDs
after generating a number of values:
</p>
1387
<pre>
1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398
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));
        }
    }
1399 1400 1401 1402 1403
}
</pre>
<p>
Some values are:
</p>
1404
<table class="main">
1405 1406 1407 1408 1409
<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>
1410 1411
<p>
To help non-mathematicians understand what those numbers mean, here a comparison:
Thomas Mueller's avatar
Thomas Mueller committed
1412
one's annual risk of being hit by a meteorite is estimated to be one chance in 17 billion,
1413 1414 1415
that means the probability is about 0.000'000'000'06.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1416 1417 1418
<h2 id="spatial_features">Spatial Features</h2>
<p>
H2 supports the geometry data type and spatial indexes if
1419
the <a href="https://projects.eclipse.org/projects/locationtech.jts">JTS Topology Suite</a>
Thomas Mueller's avatar
Thomas Mueller committed
1420 1421
is in the classpath.
To run the H2 Console tool with the JTS tool, you need to download the
1422
<a href="https://search.maven.org/remotecontent?filepath=org/locationtech/jts/jts-core/1.15.0/jts-core-1.15.0.jar">JTS-CORE 1.15.0 jar file</a>
Thomas Mueller's avatar
Thomas Mueller committed
1423 1424 1425 1426 1427
and place it in the h2 bin directory. Then edit the <code>h2.sh</code> file as follows:
</p>
<pre>
#!/bin/sh
dir=$(dirname "$0")
1428
java -cp "$dir/h2.jar:jts-core-1.15.0.jar:$H2DRIVERS:$CLASSPATH" org.h2.tools.Console "$@"
Thomas Mueller's avatar
Thomas Mueller committed
1429 1430 1431 1432 1433
</pre>
<p>
Here is an example SQL script to create a table with a spatial column and index:
</p>
<pre>
Thomas Mueller's avatar
Thomas Mueller committed
1434 1435 1436
CREATE TABLE GEO_TABLE(GID SERIAL, THE_GEOM GEOMETRY);
INSERT INTO GEO_TABLE(THE_GEOM) VALUES
    ('POINT(500 505)'),
Thomas Mueller's avatar
Thomas Mueller committed
1437 1438
    ('LINESTRING(550 551, 525 512, 565 566)'),
    ('POLYGON ((550 521, 580 540, 570 564, 512 566, 550 521))');
Thomas Mueller's avatar
Thomas Mueller committed
1439
CREATE SPATIAL INDEX GEO_TABLE_SPATIAL_INDEX ON GEO_TABLE(THE_GEOM);
Thomas Mueller's avatar
Thomas Mueller committed
1440 1441 1442
</pre>
<p>
To query the table using geometry envelope intersection,
Thomas Mueller's avatar
Thomas Mueller committed
1443
use the operation <code>&&</code>, as in PostGIS:
Thomas Mueller's avatar
Thomas Mueller committed
1444 1445
</p>
<pre>
Thomas Mueller's avatar
Thomas Mueller committed
1446
SELECT * FROM GEO_TABLE
Thomas Mueller's avatar
Thomas Mueller committed
1447 1448 1449 1450 1451 1452
WHERE THE_GEOM && 'POLYGON ((490 490, 536 490, 536 515, 490 515, 490 490))';
</pre>
<p>
You can verify that the spatial index is used using the "explain plan" feature:
</p>
<pre>
Thomas Mueller's avatar
Thomas Mueller committed
1453
EXPLAIN SELECT * FROM GEO_TABLE
Thomas Mueller's avatar
Thomas Mueller committed
1454 1455 1456
WHERE THE_GEOM && 'POLYGON ((490 490, 536 490, 536 515, 490 515, 490 490))';
-- Result
SELECT
Thomas Mueller's avatar
Thomas Mueller committed
1457 1458 1459 1460
    GEO_TABLE.GID,
    GEO_TABLE.THE_GEOM
FROM PUBLIC.GEO_TABLE
    /* PUBLIC.GEO_TABLE_SPATIAL_INDEX:
Thomas Mueller's avatar
Thomas Mueller committed
1461
    THE_GEOM && 'POLYGON ((490 490, 536 490, 536 515, 490 515, 490 490))' */
Thomas Mueller's avatar
Thomas Mueller committed
1462
WHERE INTERSECTS(THE_GEOM,
Thomas Mueller's avatar
Thomas Mueller committed
1463 1464 1465 1466 1467 1468 1469
    'POLYGON ((490 490, 536 490, 536 515, 490 515, 490 490))')
</pre>
<p>
For persistent databases, the spatial index is stored on disk;
for in-memory databases, the index is kept in memory.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1470 1471
<h2 id="recursive_queries">Recursive Queries</h2>
<p>
Thomas Mueller's avatar
Thomas Mueller committed
1472
H2 has experimental support for recursive queries using so called "common table expressions" (CTE).
Thomas Mueller's avatar
Thomas Mueller committed
1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494 1495 1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509 1510 1511 1512 1513 1514
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.
Thomas Mueller's avatar
Thomas Mueller committed
1515 1516
All columns of the table expression are of type <code>VARCHAR</code>,
and may need to be cast to the required data type.
Thomas Mueller's avatar
Thomas Mueller committed
1517 1518
Views with recursive queries are not supported.
Subqueries and <code>INSERT INTO ... FROM</code> with recursive queries are not supported.
Thomas Mueller's avatar
Thomas Mueller committed
1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532
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
1533
<h2 id="system_properties">Settings Read from System Properties</h2>
1534 1535
<p>
Some settings of the database can be set on the command line using
1536
<code>-DpropertyName=value</code>. It is usually not required to change those settings manually.
1537 1538 1539
The settings are case sensitive.
Example:
</p>
1540
<pre>
1541 1542 1543 1544
java -Dh2.serverCachedObjects=256 org.h2.tools.Server
</pre>
<p>
The current value of the settings can be read in the table
1545
<code>INFORMATION_SCHEMA.SETTINGS</code>.
1546 1547 1548
</p>
<p>
For a complete list of settings, see
1549
<a href="http://www.h2database.com/javadoc/org/h2/engine/SysProperties.html">SysProperties</a>.
1550 1551
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1552
<h2 id="server_bind_address">Setting the Server Bind Address</h2>
1553 1554 1555
<p>
Usually server sockets accept connections on any/all local addresses.
This may be a problem on multi-homed hosts.
1556
To bind only to one address, use the system property <code>h2.bindAddress</code>.
1557
This setting is used for both regular server sockets and for TLS server sockets.
1558 1559 1560
IPv4 and IPv6 address formats are supported.
</p>

Thomas Mueller's avatar
Thomas Mueller committed
1561
<h2 id="file_system">Pluggable File System</h2>
1562
<p>
Thomas Mueller's avatar
Thomas Mueller committed
1563 1564 1565 1566
This database supports a pluggable file system API.
The file system implementation is selected using a file name prefix.
Internally, the interfaces are very similar to the Java 7 NIO2 API, but do not (yet) use or require Java 7.
The following file systems are included:
1567
</p>
1568
<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
1569
</li><li><code>split:</code> file system that splits files in 1 GB files (stackable with other file systems).
1570 1571
</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).
Noel Grandin's avatar
Noel Grandin committed
1572
    Please note that there currently is a file size limitation of 2 GB when using this file system.
Thomas Mueller's avatar
Thomas Mueller committed
1573
    To work around this limitation, combine it with the split file system: <code>split:nioMapped:test</code>.
Thomas Mueller's avatar
Thomas Mueller committed
1574 1575
</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).
1576
</li><li><code>nioMemFS:</code> stores data outside of the VM's heap - useful for large memory DBs without incurring GC costs.
1577 1578
</li>
<li>
Thomas Mueller Graf's avatar
Thomas Mueller Graf committed
1579 1580 1581 1582 1583 1584
    <code>nioMemLZF:</code> stores compressed data outside of the VM's heap -
    useful for large memory DBs without incurring GC costs.
    Use "nioMemLZF:12:" to tweak the % of blocks that are stored uncompressed.
    If you size this to your working set correctly,
    compressed storage is roughly the same performance as uncompressed.
    The default value is 1%.
1585 1586
</li></ul>
<p>
1587 1588
As an example, to use the the <code>nio</code> file system, use the following database URL:
<code>jdbc:h2:nio:~/test</code>.
1589 1590
</p>
<p>
1591
To register a new file system, extend the classes <code>org.h2.store.fs.FilePath, FileBase</code>,
1592
and call the method <code>FilePath.register</code> before using it.
1593
</p>
1594 1595 1596
<p>
For input streams (but not for random access files), URLs may be used in addition to the registered file systems.
Example: <code>jar:file:///c:/temp/example.zip!/org/example/nested.csv</code>.
Thomas Mueller's avatar
Thomas Mueller committed
1597
To read a stream from the classpath, use the prefix <code>classpath:</code>, as in
Thomas Mueller's avatar
Thomas Mueller committed
1598
<code>classpath:/org/h2/samples/newsfeed.sql</code>.
1599
</p>
1600

Thomas Mueller's avatar
Thomas Mueller committed
1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612
<h2 id="file_system_split">Split File System</h2>
<p>
The file system prefix <code>split:</code> is used to split logical files into multiple physical files,
for example so that a database can get larger than the maximum file system size of the operating system.
If the logical file is larger than the maximum file size, then the file is split as follows:
</p>
<ul><li><code>&lt;fileName&gt;</code> (first block, is always created)
</li><li><code>&lt;fileName&gt;.1.part</code> (second block)
</li></ul>
<p>
More physical files (<code>*.2.part, *.3.part</code>) are automatically created / deleted if needed.
The maximum physical file size of a block is 2^30 bytes, which is also called 1 GiB or 1 GB.
Thomas Mueller's avatar
Thomas Mueller committed
1613 1614 1615
However this can be changed if required, by specifying the block size in the file name.
The file name format is: <code>split:&lt;x&gt;:&lt;fileName&gt;</code> where the file size per block is 2^x.
For 1 MiB block sizes, use x = 20 (because 2^20 is 1 MiB).
Thomas Mueller's avatar
Thomas Mueller committed
1616 1617 1618 1619
The following file name means the logical file is split into 1 MiB blocks: <code>split:20:test.h2.db</code>.
An example database URL for this case is <code>jdbc:h2:split:20:~/test</code>.
</p>

1620 1621 1622 1623 1624 1625 1626 1627
<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>
1628
The conversion itself is done internally via <code>'script to'</code> and <code>'runscript from'</code>. After the conversion process, the files will be
1629
renamed from
1630
</p>
1631
<ul>
1632 1633
<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>
1634
</li></ul>
1635
<p>
1636 1637
by default. Also, the temporary script will be written to the database directory instead of a temporary directory.
Both defaults can be customized via
1638
</p>
1639
<ul>
1640 1641
<li><code>org.h2.upgrade.DbUpgrade.setDeleteOldDb(boolean)</code>
</li><li><code>org.h2.upgrade.DbUpgrade.setScriptInTmpDir(boolean)</code>
1642
</li></ul>
1643
<p>
1644 1645
prior opening a database connection.
</p>
1646
<p>
Thomas Mueller's avatar
Thomas Mueller committed
1647
Since version 1.2.140 it is possible to let the old h2 classes (v 1.2.128) connect to the database.
Thomas Mueller's avatar
Thomas Mueller committed
1648 1649
The automatic upgrade .jar file must be present, and the URL must start with <code>jdbc:h2v1_1:</code>
(the JDBC driver class is <code>org.h2.upgrade.v1_1.Driver</code>).
Thomas Mueller's avatar
Thomas Mueller committed
1650 1651 1652
If the database should automatically connect using the old version if a database with the old format exists
(without upgrade), and use the new version otherwise, then append <code>;NO_UPGRADE=TRUE</code>
to the database URL.
Thomas Mueller's avatar
Thomas Mueller committed
1653 1654
Please note the old driver did not process the system property <code>"h2.baseDir"</code> correctly,
so that using this setting is not supported when upgrading.
1655
</p>
1656

1657 1658 1659 1660 1661 1662 1663 1664
<h2 id="java_objects_serialization">Java Objects Serialization</h2>
<p>
Java objects serialization is enabled by default for columns of type <code>OTHER</code>, using standard Java serialization/deserialization semantics.
</p>
<p>
To disable this feature set the system property <code>h2.serializeJavaObject=false</code> (default: true).
</p>
<p>
1665 1666
Serialization and deserialization of java objects is customizable both at system level and at database level providing a
<a href="http://www.h2database.com/javadoc/org/h2/api/JavaObjectSerializer.html">JavaObjectSerializer</a> implementation:
1667
</p>
1668 1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683
<ul>
<li>
At system level set the system property <code>h2.javaObjectSerializer</code> with the
Fully Qualified Name of the <code>JavaObjectSerializer</code> interface implementation.
It will be used over the entire JVM session to (de)serialize java objects being stored in column of type OTHER.
Example <code>h2.javaObjectSerializer=com.acme.SerializerClassName</code>.
</li>
<li>
At database level execute the SQL statement <code>SET JAVA_OBJECT_SERIALIZER 'com.acme.SerializerClassName'</code>
or append <code>;JAVA_OBJECT_SERIALIZER='com.acme.SerializerClassName'</code> to the database URL: <code>jdbc:h2:~/test;JAVA_OBJECT_SERIALIZER='com.acme.SerializerClassName'</code>.
<p>
Please note that this SQL statement can only be executed before any tables are defined.
</p>
</li>
</ul>

1684 1685
<h2 id="custom_data_types_handler_api">Custom Data Types Handler API</h2>
<p>
1686
It is possible to extend the type system of the database by providing your own implementation
1687 1688 1689
of minimal required API basically consisting of type identification and conversion routines.
</p>
<p>
1690 1691
In order to enable this feature, set the system property <code>h2.customDataTypesHandler</code> (default: null) to the fully qualified name of the class providing
<a href="http://www.h2database.com/javadoc/org/h2/api/CustomDataTypesHandler.html">CustomDataTypesHandler</a> interface implementation. <br />
1692
The instance of that class will be created by H2 and used to:
1693
</p>
1694 1695 1696 1697 1698 1699 1700 1701 1702 1703 1704 1705 1706 1707
<ul>
<li>resolve the names and identifiers of extrinsic data types.
</li>
<li>convert values of extrinsic data types to and from values of built-in types.
</li>
<li>provide order of the data types.
</li>
</ul>
<p>This is a system-level setting, i.e. affects all the databases.</p>

<p><b>Note: </b>Please keep in mind that this feature may not possibly provide the same ABI stability level as other features as it exposes many of the H2 internals. You may be required to update your code occasionally due to internal changes in H2 if you are going to use this feature.
</p>


Thomas Mueller's avatar
Thomas Mueller committed
1708
<h2 id="limits_limitations">Limits and Limitations</h2>
1709 1710 1711 1712
<p>
This database has the following known limitations:
</p>
<ul>
Thomas Mueller's avatar
Thomas Mueller committed
1713 1714
<li>Database file size limit:
    4 TB (using the default page size of 2 KB) or higher (when using a larger page size).
Thomas Mueller's avatar
Thomas Mueller committed
1715
    This limit is including CLOB and BLOB data.
Thomas Mueller's avatar
Thomas Mueller committed
1716 1717 1718 1719 1720
</li><li>The maximum file size for FAT or FAT32 file systems is 4 GB.
    That means when using FAT or FAT32, the limit is 4 GB for the data. This is the limitation of the file system.
    The database does provide a workaround for this problem, it is to use the file name prefix <code>split:</code>.
    In that case files are split into files of 1 GB by default.
    An example database URL is: <code>jdbc:h2:split:~/test</code>.
Thomas Mueller's avatar
Thomas Mueller committed
1721
</li><li>The maximum number of rows per table is 2^64.
1722
</li><li>The maximum number of open transactions is 65535.
1723
</li><li>Main memory requirements: The larger the database, the more main memory is required.
1724
    With the current storage mechanism (the page store),
Thomas Mueller's avatar
Thomas Mueller committed
1725
    the minimum main memory required is around 1 MB for each 8 GB database file size.
Thomas Mueller's avatar
Thomas Mueller committed
1726
</li><li>Limit on the complexity of SQL statements.
1727
Statements of the following form will result in a stack overflow exception:
1728
<pre>
1729 1730 1731 1732 1733
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
1734 1735 1736 1737 1738 1739
    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;
1740
    maximum row length, index row length, select row length;
Thomas Mueller's avatar
Thomas Mueller committed
1741
    maximum length of a varchar column, decimal column, literal in a statement.
Thomas Mueller's avatar
Thomas Mueller committed
1742
</li><li>Querying from the metadata tables is slow if there are many tables (thousands).
1743 1744 1745 1746
</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
1747
<h2 id="glossary_links">Glossary and Links</h2>
1748
<table class="main">
Thomas Mueller's avatar
Thomas Mueller committed
1749 1750 1751 1752 1753 1754 1755
    <tr>
        <th>Term</th>
        <th>Description</th>
    </tr>
    <tr>
        <td>AES-128</td>
        <td>A block encryption algorithm. See also: <a
1756 1757
            href="https://en.wikipedia.org/wiki/Advanced_Encryption_Standard">Wikipedia:
        Advanced Encryption Standard</a></td>
Thomas Mueller's avatar
Thomas Mueller committed
1758 1759 1760 1761 1762 1763
    </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
1764 1765
            href="https://en.wikipedia.org/wiki/Birthday_problem">Wikipedia:
        Birthday problem</a></td>
Thomas Mueller's avatar
Thomas Mueller committed
1766 1767 1768 1769
    </tr>
    <tr>
        <td>Digest</td>
        <td>Protocol to protect a password (but not to protect data).
1770
        See also: <a href="https://www.ietf.org/rfc/rfc2617.txt">RFC
Thomas Mueller's avatar
Thomas Mueller committed
1771 1772 1773 1774 1775
        2617: HTTP Digest Access Authentication</a></td>
    </tr>
    <tr>
        <td>HTTPS</td>
        <td>A protocol to provide security to HTTP connections. See
1776
        also: <a href="https://www.ietf.org/rfc/rfc2818.txt">RFC 2818:
Thomas Mueller's avatar
Thomas Mueller committed
1777 1778 1779 1780 1781
        HTTP Over TLS</a></td>
    </tr>
    <tr>
        <td>Modes of Operation</td>
        <td><a
1782 1783
            href="https://en.wikipedia.org/wiki/Block_cipher_mode_of_operation">Wikipedia:
        Block cipher mode of operation</a></td>
Thomas Mueller's avatar
Thomas Mueller committed
1784 1785 1786 1787
    </tr>
    <tr>
        <td>Salt</td>
        <td>Random number to increase the security of passwords. See
1788
        also: <a href="https://en.wikipedia.org/wiki/Key_derivation_function">Wikipedia:
Thomas Mueller's avatar
Thomas Mueller committed
1789 1790 1791 1792 1793
        Key derivation function</a></td>
    </tr>
    <tr>
        <td>SHA-256</td>
        <td>A cryptographic one-way hash function. See also: <a
1794 1795
            href="https://en.wikipedia.org/wiki/Secure_Hash_Algorithms">Wikipedia:
            Secure Hash Algorithms</a></td>
Thomas Mueller's avatar
Thomas Mueller committed
1796 1797 1798
    </tr>
    <tr>
        <td>SQL Injection</td>
1799 1800
        <td>A security vulnerability where an application embeds SQL
        statements or expressions in user input. See also: <a
1801 1802
            href="https://en.wikipedia.org/wiki/SQL_injection">Wikipedia:
        SQL injection</a></td>
Thomas Mueller's avatar
Thomas Mueller committed
1803 1804 1805 1806 1807 1808 1809 1810 1811 1812 1813
    </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:
1814
        <a href="https://docs.oracle.com/javase/7/docs/technotes/guides/security/jsse/JSSERefGuide.html">Java Secure Socket
Thomas Mueller's avatar
Thomas Mueller committed
1815 1816
        Extension (JSSE)</a></td>
    </tr>
1817 1818 1819
</table>

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