advanced.html 44.4 KB
Newer Older
1 2 3 4 5
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<!-- 
Copyright 2004-2006 H2 Group. Licensed under the H2 License, Version 1.0 (http://h2database.com/html/license.html). 
Initial Developer: H2 Group
-->
6
<html><head><meta http-equiv="Content-Type" content="text/html;charset=utf-8" /><title>
7
Advanced Topics
8
</title><link rel="stylesheet" type="text/css" href="stylesheet.css" />
9 10 11 12 13
<script type="text/javascript" src="navigation.js"></script>
</head><body onload="frameMe();">
<table class="content"><tr class="content"><td class="content"><div class="contentDiv">

<h1>Advanced Topics</h1>
14
<a href="#result_sets">
15
    Result Sets</a><br />
16
<a href="#large_objects">
17
    Large Objects</a><br />
18
<a href="#linked_tables">
19
    Linked Tables</a><br />
20
<a href="#transaction_isolation">
21
    Transaction Isolation</a><br />
22
<a href="#clustering">
23
    Clustering / High Availability</a><br />
24
<a href="#two_phase_commit">
25
    Two Phase Commit</a><br />
26
<a href="#compatibility">
27
    Compatibility</a><br />
28
<a href="#windows_service">
29
    Run as Windows Service</a><br />
30
<a href="#odbc_driver">
31
    ODBC Driver</a><br />
32
<a href="#acid">
33
    ACID</a><br />
34 35
<a href="#durability_problems">
    Durability Problems</a><br />  
36
<a href="#using_recover_tool">
37
    Using the Recover Tool</a><br />
38
<a href="#file_locking_protocols">
39
    File Locking Protocols</a><br />
40
<a href="#sql_injection">
41
    Protection against SQL Injection</a><br />
42
<a href="#security_protocols">
43
    Security Protocols</a><br />
44
<a href="#uuid">
45
    Universally Unique Identifiers (UUID)</a><br />
46
<a href="#system_properties">
47
    Settings Read from System Properties</a><br />
48
<a href="#glossary_links">
49
    Glossary and Links</a><br />
50

51
<br /><a name="result_sets"></a>
52 53 54 55 56 57 58 59 60 61 62 63 64 65 66
<h2>Result Sets</h2>

<h3>Limiting the Number of Rows</h3>
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.
This can be done using LIMIT in a query (example: SELECT * FROM TEST LIMIT 100),
or by using Statement.setMaxRows(max).

<h3>Large Result Sets and External Sorting</h3>
For result set larger than 1000 rows, the result is buffered to disk. If ORDER BY is used,
the sorting is done using an 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.

67
<br /><a name="large_objects"></a>
68 69 70 71 72 73 74 75 76 77 78 79
<h2>Large Objects</h2>

<h3>Storing and Reading Large Objects</h3>
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.
To store a BLOB, use PreparedStatement.setBinaryStream. To store a CLOB, use
PreparedStatement.setCharacterStream. To read a BLOB, use ResultSet.getBinaryStream,
and to read a CLOB, use ResultSet.getCharacterStream.
If the client/server mode is used, the BLOB and CLOB data is fully read into memory when
accessed. In this case, the size of a BLOB or CLOB is limited by the memory.

80
<br /><a name="linked_tables"></a>
81 82 83 84 85 86 87 88 89
<h2>Linked Tables</h2>

This database supports linked tables, which means tables that don't exist in the current database but
are just links to another database. To create such a link, use the CREATE LINKED TABLE statement:
<pre>
CREATE LINKED TABLE LINK('org.postgresql.Driver', 'jdbc:postgresql:test', 'sa', 'sa', 'TEST');
</pre>
It is then possible to access the table in the usual way. 
There is a restriction when inserting data to this table: When inserting or updating rows into the table,
90
NULL and values that are not set in the insert statement are both inserted as NULL.
91 92
This may not have the desired effect if a default value in the target table is other than NULL.

93
<br /><a name="transaction_isolation"></a>
94
<h2>Transaction Isolation</h2>
95 96 97 98 99 100 101 102 103 104
<p>
This database supports the following transaction isolation levels:
</p>

<ul>
<li><b>Serializable</b><br />
	This is the default level.<br />
	To enable, execute the SQL statement	'SET LOCK_MODE 0'<br />
	or append ;LOCK_MODE=1 to the database URL: jdbc:h2:~/test;LOCK_MODE=1
</li><li><b>Read Committed</b><br />
105
	Read locks are released immediately.
106 107 108 109 110 111 112 113 114 115 116 117 118 119
	Higer concurrency is possible when using this level.<br />
	This is the isolation level used for many database systems.<br />
	To enable, execute the SQL statement	'SET LOCK_MODE 0'<br />
	or append ;LOCK_MODE=3 to the database URL: jdbc:h2:~/test;LOCK_MODE=3
</li><li><b>Read Uncommitted</b><br />
	This level means that transaction isolation is disabled.<br />
	To enable, execute the SQL statement	'SET LOCK_MODE 0'<br />
	or append ;LOCK_MODE=0 to the database URL: jdbc:h2:~/test;LOCK_MODE=0
</li>
</ul>

<p>
When using the isolation level 'serializable', dirty reads, non-repeatable reads, and phantom reads are prohibited.
</p>
120 121

<ul>
122
<li><b>Dirty Reads</b><br />
123 124
    Means a connection can read uncommitted changes made by another connection.<br />
    Possible with: read uncommitted
125
</li><li><b>Non-Repeatable Reads</b><br />
126
    A connection reads a row, another connection changes a row and commits,
127 128
    and the first connection re-reads the same row and gets the new result.<br />
    Possible with: read uncommitted, read committed
129
</li><li><b>Phantom Reads</b><br />
130 131
    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
132 133 134 135
    re-reads using the same condition and gets the new row.<br />
    Possible with: read uncommitted, read committed 
</li>
</ul>
136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158

<h3>Table Level Locking</h3>
The database allows multiple concurrent connections to the same database.
To make sure all connections only see consistent data, table level locking is used.
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.

<h3>Lock Timeout</h3>
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.

159
<br /><a name="clustering"></a>
160
<h2>Clustering / High Availability</h2>
161
<p>
162 163 164 165 166 167 168 169 170 171
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.
Clustering can only be used in the server mode (the embedded mode does not support clustering).
It is possible to restore the cluster without stopping the server, however it is critical that no other
application is changing the data in the first database while the second database is restored, so
restoring the cluster is currently a manual process.
172
</p><p>
173
To initialize the cluster, use the following steps:
174
</p>
175 176
<ul>
<li>Create a database
177
</li><li>Use the CreateCluster tool to copy the database to another location and initialize the clustering.
178
    Afterwards, you have two databases containing the same data.
179 180 181
</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>
182 183 184 185 186 187 188 189

<h3>Using the CreateCluster Tool</h3>
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.
<ul>
<li>Create two directories: server1 and server2.
    Each directory will simulate a directory on a computer.
190
</li><li>Start a TCP server pointing to the first directory.
191
    You can do this using the command line:
192
</li><pre>
193 194 195 196 197 198 199
java org.h2.tools.Server
    -tcp -tcpPort 9101
    -baseDir server1
</pre>
<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:
200
</li><pre>
201 202 203 204 205 206 207
java org.h2.tools.Server
    -tcp -tcpPort 9102
    -baseDir server2
</pre>
<li>Use the CreateCluster tool to initialize clustering.
    This will automatically create a new, empty database if it does not exist.
    Run the tool on the command line:
208
</li><pre>
209 210 211 212 213 214 215 216 217
java org.h2.tools.CreateCluster
  -urlSource jdbc:h2:tcp://localhost:9101/test
  -urlTarget jdbc:h2:tcp://localhost:9102/test
  -user sa
  -serverlist localhost:9101,localhost:9102
</pre>
<li>You can now connect to the databases using
an application or the H2 Console using the JDBC URL
jdbc:h2:tcp://localhost:9101,localhost:9102/test
218
</li><li>If you stop a server (by killing the process),
219 220
you will notice that the other machine continues to work,
and therefore the database is still accessible.
221
</li><li>To restore the cluster, you first need to delete the
222 223
database that failed, then restart the server that was stopped,
and re-run the CreateCluster tool.
224
</li></ul>
225

226 227 228 229 230 231 232 233 234
<h3>Clustering Algorithm and Limitations</h3>
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
executed with care: RANDOM_UUID(), SECURE_RAND(), SESSION_ID(), MEMORY_FREE(), MEMORY_USED(),
CSVREAD(), CSVWRITE(), RAND() [when not using a seed]. Those functions should not be used
directly in modifying statements (for example INSERT, UPDATE, or MERGE). However, they can be used
in read-only statements and the result can then be used for modifying statements.

235
<br /><a name="two_phase_commit"></a>
236 237 238 239
<h2>Two Phase Commit</h2>
The two phase commit protocol is supported. 2-phase-commit works as follows:
<ul>
<li>Autocommit needs to be switched off
240 241 242
</li><li>A transaction is started, for example by inserting a row
</li><li>The transaction is marked 'prepared' by executing the SQL statement
    </li><code>PREPARE COMMIT transactionName</code>
243
<li>The transaction can now be committed or rolled back
244
</li><li>If a problem occurs before the transaction was successfully committed or rolled back
245
    (for example because a network problem occurred), the transaction is in the state 'in-doubt'
246 247
</li><li>When re-connecting to the database, the in-doubt transactions can be listed
    with </li><code>SELECT * FROM INFORMATION_SCHEMA.IN_DOUBT</code>
248
<li>Each transaction in this list must now be committed or rolled back by executing
249
    </li><code>COMMIT TRANSACTION transactionName</code> or
250 251
    <code>ROLLBACK TRANSACTION transactionName</code>
<li>The database needs to be closed and re-opened to apply the changes
252
</li></ul>
253

254
<br /><a name="compatibility"></a>
255 256 257 258 259 260 261 262 263 264 265
<h2>Compatibility</h2>

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.

<h3>Transaction Commit when Autocommit is On</h3>
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.

<h3>Keywords / Reserved Words</h3>
266
<p>
267 268
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:
269
</p><p>
270 271 272
CURRENT_TIMESTAMP, CURRENT_TIME, CURRENT_DATE, CROSS, DISTINCT, EXCEPT, EXISTS, FROM,
FOR, FALSE, FULL, GROUP, HAVING, INNER, INTERSECT, IS, JOIN, LIKE, MINUS, NATURAL, NOT, NULL,
ON, ORDER, PRIMARY, ROWNUM, SELECT, SYSDATE, SYSTIME, SYSTIMESTAMP, TODAY, TRUE, UNION, WHERE
273
</p><p>
274 275
Certain words of this list are keywords because they are functions that can be used without '()' for compatibility,
for example CURRENT_TIMESTAMP.
276
</p>
277

278
<br /><a name="windows_service"></a>
279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309
<h2>Run as Windows Service</h2>
Using a native wrapper / adapter, Java applications can be run as a Windows Service. 
There are various tools available to do that. The Java Service Wrapper from Tanuki Software, Inc.
(<a href="http://wrapper.tanukisoftware.org">http://wrapper.tanukisoftware.org</a>)
is included in the installation. Batch files are provided to install, start, stop and uninstall the H2 Database Engine Service.
This service contains the TCP Server and the H2 Console web application.
The batch files are located in the directory H2/service.

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

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

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

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

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

310
<br /><a name="odbc_driver"></a>
311 312 313 314 315 316 317
<h2>ODBC Driver</h2>
The ODBC driver of this database is currently not very stable and only tested superficially
with a few applications (OpenOffice 2.0, Microsoft Excel and Microsoft Access) and
data types (INT and VARCHAR), and should not be used for production applications.
Only a Windows version of the driver is available at this time.

<h3>ODBC Installation</h3>
318
<p>
319 320 321 322 323 324
Before the ODBC driver can be used, it needs to be installed. To do this,
double click on h2odbcSetup.exe. If you do this the first time, it will ask you to locate the
driver dll (h2odbc.dll). If you already installed it, the ODBC administration dialog will open
where you can create new or modify existing data sources.
When you create a new H2 ODBC data source, a dialog window will appear
and ask for the database settings:
325
</p>
326
<img src="odbcDataSource.png" alt="ODBC Configuration" />
327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353

<h3>Log Option</h3>
The driver is able to log operations to a file.
To enable logging, the log file name must be set in the registry under the key
CURRENT_USER/Software/H2/ODBC/LogFile. This key will only be read when the
driver starts, so you need to make sure all applications that may use the driver
are closed before changing this setting.
If this registry entry is not found when the driver starts, logging is disabled.
A sample registry key file may look like this:
<pre>
Windows Registry Editor Version 5.00

[HKEY_CURRENT_USER\Software\H2\ODBC]
"LogFile"="C:\\temp\\h2odbc.txt"
</pre>

<h3>Security Considerations</h3>
Currently, the ODBC does not encrypt the password before sending it over TCP/IP to the server.
This may be a problem if an attacker can listen to the data transferred between the ODBC client
and the server, because the password is readable to the attacker.
Also, it is currently not possible to use encrypted SSL connections.
The password for a data source is stored unencrypted in the registry.
Therefore the ODBC driver should not be used where security is important.

<h3>Uninstalling</h3>
To uninstall the ODBC driver, double click on h2odbcUninstall.exe. This will uninstall the driver.

354
<br /><a name="acid"></a>
355
<h2>ACID</h2>
356
In the database world, ACID stands for:
357
<ul>
358
<li>Atomicity: Transactions must be atomic, meaning either all tasks are performed or none.
359
</li><li>Consistency: All operations must comply with the defined constraints.
360
</li><li>Isolation: Transactions must be isolated from each other.
361
</li><li>Durability: Committed transaction will not be lost.
362
</li></ul>
363 364 365 366 367 368 369 370 371

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

<h3>Consistency</h3>
This database is always in a consistent state.
Referential integrity rules are always enforced.

<h3>Isolation</h3>
372 373 374 375
For H2, the default isolation level is 'serializable', which means complete isolation. 
The default transaction isolation level for many other databases 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'.
376 377 378

<h3>Durability</h3>
This database does not guarantee that all committed transactions survive a power failure.
379
Tests show that all databases sometimes lose transactions on power failure (for details, see below).
380 381 382 383
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.

384 385
<br /><a name="durability_problems"></a>
<h2>Durability Problems</h2>
386 387
<p>
Complete durability means all committed transaction survive a power failure.
388
Some databases claim they can guarantee durability, but such claims are wrong.
389
A durability test was run against H2, HSQLDB, PostgreSQL, and Derby.
390 391
All of those databases sometimes lose committed transactions.
The test is included in the H2 download, see org.h2.test.poweroff.Test. 
392 393
</p>

394 395
<h3>Ways to (Not) Achieve Durability</h3>
<p>
396 397 398
Making sure that committed transaction 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 
399 400
is to use the 'synchronous write' file access mode. In Java, RandomAccessFile
supports the modes "rws" and "rwd":
401 402
</p>
<ul>
403 404
<li>rwd: Every update to the file's content is written synchronously to the underlying storage device. 
</li><li>rws: In addition to rwd, every update to the metadata is written synchronously.</li>
405 406
</ul>
<p>
407 408
This feature is used by Derby.
A test (org.h2.test.poweroff.TestWrite) with one of those modes achieves around 50 thousand write operations per second.
409
Even when the operating system write buffer is disabled, the write rate is around 50 thousand operations per second.
410 411 412 413 414
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.
415 416
</p>
<p>
417
Buffers can be flushed by calling the function fsync. There are two ways to do that in Java:
418
</p>
419
<ul>
420
<li>FileDescriptor.sync(). The documentation says that this forces all system buffers to synchronize with the underlying device.
421
Sync is supposed to return after all in-memory modified copies of buffers associated with this FileDescriptor
422
have been written to the physical medium.
423
</li><li>FileChannel.force() (since JDK 1.4). This method is supposed to force any updates to this channel's file
424
to be written to the storage device that contains it.
425
</li></ul>
426
<p>
427
By default, MySQL calls fsync for each commit. When using one of those methods, only around 60 write operations 
428 429 430
per second can be achieved, which is consistent with the RPM rate of the hard drive used.
Unfortunately, even when calling FileDescriptor.sync() or FileChannel.force(), 
data is not always persisted to the hard drive, because most hard drives do not obey
431 432 433 434 435 436 437 438 439 440 441
fsync(): see 'Your Hard Drive Lies to You' at http://hardware.slashdot.org/article.pl?sid=05/05/13/0529252.
In Mac OS X fsync does not flush hard drive buffers:
http://lists.apple.com/archives/darwin-dev/2005/Feb/msg00072.html.
So the situation is confusing, and tests prove there is a problem.
</p>
<p>
Trying to flush hard drive buffers hard, and if you do the performance is very bad.
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.
442 443
</p>
<p>
444 445 446 447
In H2, after a power failure, a bit more than one second of committed transactions may be lost.
To change the behavior, use SET WRITE_DELAY and CHECKPOINT SYNC.
Most other databases support commit delay as well. 
In the performance comparison, commit delay was used for all databases that support it.
448
</p>
449

450 451 452
<h3>Running the Durability Test</h3>
To test the durability / non-durability of this and other databases, you can use the test application
in the package org.h2.test.poweroff. Two computers with network connection are required to run this test.
453
One computer just listens, while the test application is run (and power is cut) on the other computer.
454 455 456 457
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.
458 459 460 461
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.
462

463
<br /><a name="using_recover_tool"></a>
464 465 466 467 468 469 470 471 472 473 474 475
<h2>Using the Recover Tool</h2>
The recover tool can be used to extract the contents of a data file, even if the database is corrupted.
At this time, it does not extract the content of the log file or large objects (CLOB or BLOB).
To run the tool, type on the command line:
<pre>
java org.h2.tools.Recover
</pre>
For each database in the current directory, a text file will be created.
This file contains raw insert statement (for the data) and data definition (DDL) statement to recreate
the schema of the database. This file cannot be executed directly, as the raw insert statements
don't have the correct table names, so the file needs to be pre-processed manually before executing.

476
<br /><a name="file_locking_protocols"></a>
477
<h2>File Locking Protocols</h2>
478
<p>
479 480 481
Whenever a database is opened, a lock file is created to signal other processes
that the database is in use. If database is closed, or if the process that opened
the database terminates, this lock file is deleted.
482
</p><p>
483 484 485 486 487 488 489 490
In special cases (if the process did not terminate normally, for example because
there was a blackout), the lock file is not deleted by the process that created it.
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'.
491
</p>
492 493 494 495 496 497 498 499 500

<h3>File Locking Method 'File'</h3>
The default method for database file locking is the 'File Method'. The algorithm is:
<ul>
<li>When the lock file does not exist, it is created (using the atomic operation File.createNewFile).
Then, the process waits a little bit (20ms) and checks the file again. If the file was changed
during this time, the operation is aborted. This protects against a race condition
when a process deletes the lock file just after one create it, and a third process creates
the file again. It does not occur if there are only two writers.
501
</li><li>
502 503 504 505 506 507 508 509
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.
510
</li><li>
511 512 513 514 515 516 517 518 519
If the lock file exists, and it was modified in the 20 ms, the process waits for some time (up to 10 times).
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.
520
</li></ul>
521 522 523 524 525 526 527
<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.
528
</p>
529 530 531 532 533 534 535 536 537

<h3>File Locking Method 'Socket'</h3>
There is a second locking mechanism implemented, but disabled by default.
The algorithm is:
<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.
538
</li><li>If the lock file exists, and the lock method is 'file', then the software switches
539
to the 'file' method.
540
</li><li>If the lock file exists, and the lock method is 'socket', then the process
541 542 543 544
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
died (for example due to a blackout, or abnormal termination of the virtual machine),
then the port was released. The new process deletes the lock file and starts again.
545
</li></ul>
546 547 548 549 550
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.

551
<br /><a name="sql_injection"></a>
552 553
<h2>Protection against SQL Injection</h2>
<h3>What is SQL Injection</h3>
554 555
This database engine provides a solution for the security vulnerability known as 'SQL Injection'.
Here is a short description of what SQL injection means.
556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614
Some applications build SQL statements with embedded user input such as:
<pre>
String sql = "SELECT * FROM USERS WHERE PASSWORD='"+pwd+"'";
ResultSet rs = conn.createStatement().executeQuery(sql);
</pre>
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 
such as (in this example) this password: ' OR ''='. In this case the statement becomes:
<pre>
SELECT * FROM USERS WHERE PASSWORD='' OR ''='';
</pre>
Which is always true no matter what the password stored in the database is. 
For more information about SQL Injection, see Glossary and Links.

<h3>Disabling Literals</h3>
SQL Injection is not possible if user input is not directly embedded in SQL statements.
A simple solution for the problem above is to use a PreparedStatement:
<pre>
String sql = "SELECT * FROM USERS WHERE PASSWORD=?";
PreparedStatement prep = conn.prepareStatement(sql);
prep.setString(1, pwd);
ResultSet rs = prep.executeQuery();
</pre>
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:
<pre>
SET ALLOW_LITERALS NONE;
</pre>
Afterwards, SQL statements with text and number literals are not allowed any more.
That means, SQL statement of the form WHERE NAME='abc' or WHERE CustomerId=10 will fail.
It is still possible to use PreparedStatements and parameters as described above. Also, it is still possible to generate
SQL statements dynamically, and use the Statement API, as long as the SQL statements
do not include literals.
There is also a second mode where number literals are allowed: SET ALLOW_LITERALS NUMBERS.
To allow all literals, execute SET ALLOW_LITERALS ALL (this is the default setting).
Literals can only be enabled or disabled by an administrator.

<h3>Using Constants</h3>
Disabling literals also means disabling hard-coded 'constant' literals. This database supports
defining constants using the CREATE CONSTANT command. Constants can be defined only 
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:
<pre>
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>
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.

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

615
<br /><a name="security_protocols"></a>
616 617 618 619 620 621
<h2>Security Protocols</h2>
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.

<h3>User Password Encryption</h3>
622
<p>
623 624 625 626 627 628 629 630 631 632 633
When a user tries to connect to a database, the combination of
user name, @, and password hashed using SHA-256, and this hash value
is transmitted to the database.
This step does not try to an attacker from re-using the value if he is able to listen to the
(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.
634
</p><p>
635 636 637 638
When a new database or user is created, a new cryptographically secure
random salt value is generated. The size of the salt is 64 bit.
Using the random salt reduces the risk of an attacker pre-calculating hash values
for many different (commonly used) passwords.
639
</p><p>
640 641 642 643 644 645 646 647 648 649 650
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
user-password hash value with the stored salt value and calculated the
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.
If the data is protected by storing it on another computer and only remotely, then the iteration count is not required at all.
651
</p>
652 653

<h3>File Encryption</h3>
654
<p>
655 656 657 658
The database files can be encrypted using two different algorithms: AES-128 and
XTEA (using 32 rounds). The reasons for supporting XTEA is performance
(XTEA is about twice as fast as AES) and to have an alternative algorithm if
AES is suddenly broken.
659
</p><p>
660 661 662
When a user tries to connect to an encrypted database, the combination of the word
'file', @, and the file password is hashed using SHA-256. This hash value is
transmitted to the server.
663
</p><p>
664 665 666 667 668
When a new database file is created, a new cryptographically secure
random salt value is generated. The size of the salt is 64 bit.
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.
669
</p><p>
670 671 672 673 674
The resulting hash value is used as the key for the block cipher algorithm
(AES-128 or XTEA with 32 rounds). Then, an initialization vector (IV) key
is calculated by hashing the key again using SHA-256.
This is to make sure the IV is unknown to the attacker.
The reason for using a secret IV is to protect against watermark attacks.
675
</p><p>
676 677 678 679
Before saving a block of data (each block is 8 bytes long), the following operations are executed:
First, the IV is calculated by encrypting the block number with the IV key (using the same
block cipher algorithm). This IV is combined with the plain text using XOR. The resulting data is
encrypted using the AES-128 or XTEA algorithm.
680
</p><p>
681 682
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.
683
</p><p>
684 685 686 687
Therefore, the block cipher modes 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
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.
688 689 690 691 692 693 694 695
</p><p>
Database encryption is meant for securing the database while it is not in use (stolen laptop and so on).
It is not meant for cases where the attacker has access to files while the database is in use. 
When he has write access, he can for example replace pieces of files with pieces of older versions 
and manipulate data like this.
</p><p>
File encryption slows down the performance of the database engine. Compared to unencrypted mode, 
database operations take about 2.2 times longer when using XTEA, and 2.5 times longer using AES (embedded mode).
696
</p>
697 698 699 700 701 702 703 704 705 706 707

<h3>SSL/TLS Connections</h3>
Remote SSL/TLS connections are supported using the Java Secure Socket Extension
(SSLServerSocket / SSLSocket). By default, anonymous SSL is enabled.
The default cipher suite is <code>SSL_DH_anon_WITH_RC4_128_MD5</code>.

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

708
<br /><a name="uuid"></a>
709
<h2>Universally Unique Identifiers (UUID)</h2>
710
This database supports the UUIDs. Also supported is a function to create new UUIDs using 
711 712 713
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'.
714
Standardized randomly generated UUIDs have 122 random bits.
715 716
4 bits are used for the version (Randomly generated UUID), and 2 bits for the variant (Leach-Salz).
This database supports generating such UUIDs using the built-in function RANDOM_UUID().
717
Here is a small program to estimate the probability of having two identical UUIDs
718 719 720
after generating a number of values:
<pre>
double x = Math.pow(2, 122);
721
for(int i=35; i&lt;62; i++) {
722 723 724 725 726 727 728 729 730 731 732 733 734 735 736
    double n = Math.pow(2, i);
    double p = 1 - Math.exp(-(n*n)/(2*x));
    String ps = String.valueOf(1+p).substring(1); 
    System.out.println("2^"+i+"="+(1L&lt;&lt;i)+" probability: 0"+ps);
}         
</pre>
Some values are:
<pre>
2^36=68'719'476'736 probability: 0.000'000'000'000'000'4
2^41=2'199'023'255'552 probability: 0.000'000'000'000'4
2^46=70'368'744'177'664 probability: 0.000'000'000'4
</pre>
One's annual risk of being hit by a meteorite is estimated to be one chance in 17 billion, 
that means the probability is about 0.000'000'000'06.

737
<br /><a name="system_properties"></a>
738
<h2>Settings Read from System Properties</h2>
739 740 741 742 743 744 745 746 747
<p>
Some settings of the database can be set on the command line using
-DpropertyName=value. It is usually not required to change those settings manually.
The settings are case sensitive. 
Example:
</p>
<pre>
java -Dh2.serverCachedObjects=256 org.h2.tools.Server
</pre>
748
<p>
749 750
The current value of the settings can be read in the table
INFORMATION_SCHEMA.SETTINGS
751
</p>
752 753 754 755 756 757
<table><tr>
<th>Setting</th>
<th>Default</th>
<th>Description</th></tr>
<tr><td>h2.check</td><td>true</td><td>Assertions in the database engine</td></tr>
<tr><td>h2.check2</td><td>false</td><td>Additional assertions</td></tr>
758 759 760 761
<tr><td>h2.clientTraceDirectory</td><td>trace.db/</td><td>Directory where the trace files of the JDBC client are stored (only for client / server)</td></tr>
<tr><td>h2.emergencySpaceInitial</td><td>1048576</td><td>Size of 'reserve' file to detect disk full problems early</td></tr>
<tr><td>h2.emergencySpaceMin</td><td>131072</td><td>Minimum size of 'reserve' file</td></tr>
<tr><td>h2.lobCloseBetweenReads</td><td>false</td><td>Close LOB files between read operations</td></tr>
762 763
<tr><td>h2.lobFilesInDirectories</td><td>false</td><td>Store LOB files in subdirectories</td></tr>
<tr><td>h2.lobFilesPerDirectory</td><td>256</td><td>Maximum number of LOB files per directory</td></tr>
764 765 766
<tr><td>h2.logAllErrors</td><td>false</td><td>Write stack traces of any kind of error to a file</td></tr>
<tr><td>h2.logAllErrorsFile</td><td>h2errors.txt</td><td>File name to log errors</td></tr>
<tr><td>h2.maxFileRetry</td><td>16</td><td>Number of times to retry file delete and rename</td></tr>
767
<tr><td>h2.multiThreadedKernel</td><td>false</td><td>Allow multiple sessions to run concurrently</td></tr>
768 769 770
<tr><td>h2.objectCache</td><td>true</td><td>Cache commonly used objects (integers, strings)</td></tr>
<tr><td>h2.objectCacheMaxPerElementSize</td><td>4096</td><td>Maximum size of an object in the cache</td></tr>
<tr><td>h2.objectCacheSize</td><td>1024</td><td>Size of object cache</td></tr>
771
<tr><td>h2.optimizeIn</td><td>true</td><td>Optimize IN(...) comparisons</td></tr>
772
<tr><td>h2.optimizeMinMax</td><td>true</td><td>Optimize MIN and MAX aggregate functions</td></tr>
773 774
<tr><td>h2.optimizeSubqueryCache</td><td>true</td><td>Cache subquery results</td></tr>
<tr><td>h2.overflowExceptions</td><td>true</td><td>Throw an exception on integer overflows</td></tr>
775 776 777 778
<tr><td>h2.recompileAlways</td><td>false</td><td>Always recompile prepared statements</td></tr>
<tr><td>h2.redoBufferSize</td><td>262144</td><td>Size of the redo buffer (used at startup when recovering)</td></tr>
<tr><td>h2.runFinalizers</td><td>true</td><td>Run finalizers to detect unclosed connections</td></tr>
<tr><td>h2.scriptDirectory</td><td></td><td>Relative or absolute directory where the script files are stored to or read from</td></tr>
779 780 781 782
<tr><td>h2.serverCachedObjects</td><td>64</td><td>TCP Server: number of cached objects per session</td></tr>
<tr><td>h2.serverSmallResultSetSize</td><td>100</td><td>TCP Server: result sets below this size are sent in one block</td></tr>
</table>

783
<br /><a name="glossary_links"></a>
784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812
<h2>Glossary and Links</h2>
<table><tr><th>Term</th><th>Description</th></tr>
<tr>
  <td>AES-128</td>
  <td>
    A block encryption algorithm. See also:
    <a href="http://en.wikipedia.org/wiki/Advanced_Encryption_Standard">Wikipedia: AES</a>
  </td>
</tr>
<tr>
  <td>Birthday Paradox</td>
  <td>
      Describes the higher than expected probability that two persons in a room have the same birthday.
    Also valid for randomly generated UUIDs. See also:
    <a href="http://en.wikipedia.org/wiki/Birthday_paradox">Wikipedia: Birthday Paradox</a>
  </td>
</tr>
<tr>
  <td>Digest</td>
  <td>
    Protocol to protect a password (but not to protect data). See also:
    <a href="http://www.faqs.org/rfcs/rfc2617.html">RFC 2617: HTTP Digest Access Authentication</a>
  </td>
</tr>
<tr>
  <td>GCJ</td>
  <td>
    GNU Compiler for Java.
    <a href="http://gcc.gnu.org/java/">http://gcc.gnu.org/java/</a> and 
813
    <a href="http://nativej.mtsystems.ch">http://nativej.mtsystems.ch/ (not free any more)</a>
814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879
  </td>
</tr>
<tr>
  <td>HTTPS</td>
  <td>
    A protocol to provide security to HTTP connections. See also:
    <a href="http://www.ietf.org/rfc/rfc2818.txt">RFC 2818: HTTP Over TLS</a>
  </td>
</tr>
<tr>
  <td>Modes of Operation</td>
  <td>
  <a href="http://en.wikipedia.org/wiki/Block_cipher_modes_of_operation">Wikipedia: Block cipher modes of operation</a>
  </td>
</tr>
<tr>
  <td>Salt</td>
  <td>
      Random number to increase the security of passwords.
      See also:
    <a href="http://en.wikipedia.org/wiki/Key_derivation_function">Wikipedia: Key derivation function</a>
  </td>
</tr>
<tr>
  <td>SHA-256</td>
  <td>
      A cryptographic one-way hash function.
      See also:
    <a href="http://en.wikipedia.org/wiki/SHA_family">Wikipedia: SHA hash functions</a>
  </td>
</tr>
<tr>
  <td>SQL Injection</td>
  <td>
      A security vulnerability where an application generates SQL statements with embedded user input.
      See also:
    <a href="http://en.wikipedia.org/wiki/SQL_injection">Wikipedia: SQL Injection</a>
  </td>
</tr>
<tr>
  <td>Watermark Attack</td>
  <td>
    Security problem of certain encryption programs where the existence of certain
    data can be proven without decrypting.
    For more information, search in the internet for 'watermark attack cryptoloop'
  </td>
</tr>
<tr>
  <td>SSL/TLS</td>
  <td>
    Secure Sockets Layer / Transport Layer Security.
    See also:
      <a href="http://java.sun.com/products/jsse/">Java Secure Socket Extension (JSSE)</a>
  </td>
</tr>
<tr>
  <td>XTEA</td>
  <td>
    A block encryption algorithm.
      See also:
    <a href="http://en.wikipedia.org/wiki/XTEA">Wikipedia: XTEA</a>
  </td>
</tr>
</table>

</div></td></tr></table></body></html>