features.html 51.6 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
Features
8
</title><link rel="stylesheet" type="text/css" href="stylesheet.css" />
9 10 11 12 13 14 15
<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>Features</h1>

<a href="#feature_list">
16
    Feature List</a><br />
17
<a href="#comparison">
18
    Comparison to Other Database Engines</a><br />
19
<a href="#products_work_with">
20
    Products that Work with H2</a><br />
21
<a href="#why_java">
22
    Why Java</a><br />
23
<a href="#connection_modes">
24
    Connection Modes</a><br />
25
<a href="#database_url">
26
    Database URL Overview</a><br />
27
<a href="#file_encryption">
28
    Connecting to a Database with File Encryption</a><br />
29
<a href="#database_file_locking">
30
    Database File Locking</a><br />
31
<a href="#database_only_if_exists">
32
    Opening a Database Only if it Already Exists</a><br />
33
<a href="#closing_the_database">
34
    Closing the Database</a><br />
35
<a href="#log_index_changes">
36
    Log Index Changes</a><br />
37
<a href="#multiple_connections">
38
    Multiple Connections</a><br />
39
<a href="#database_file_layout">
40
    Database File Layout</a><br />
41
<a href="#logging_recovery">
42
    Logging and Recovery</a><br />
43
<a href="#compatibility_modes">
44
    Compatibility Modes</a><br />
45
<a href="#trace_options">
46
    Using the Trace Options</a><br />
47
<a href="#read_only">
48
    Read Only Databases</a><br />
49
<a href="#storage_formats">
50
    Binary and Text Storage Formats</a><br />
51
<a href="#low_disk_space">
52
    Graceful Handling of Low Disk Space Situations</a><br />
53
<a href="#computed_columns">
54
    Computed Columns / Function Based Index</a><br />
55
<a href="#multi_dimensional">
56
    Multi-Dimensional Indexes</a><br />
57
<a href="#passwords">
58
    Using Passwords</a><br />
59
<a href="#user_defined_functions">
60
    User Defined Functions and Stored Procedures</a><br />
61
<a href="#triggers">
62
    Triggers</a><br />
63
<a href="#compacting">
64
    Compacting a Database</a><br />
65
<a href="#cache_settings">
66
    Cache Settings</a><br />
67

68
<br /><a name="feature_list"></a>
69 70 71 72
<h2>Feature List</h2>
<h3>Main Features</h3>
<ul>
<li>Very fast database engine
73 74 75 76 77 78 79
</li><li>Free, with source code
</li><li>Written in Java
</li><li>Supports standard SQL, JDBC API
</li><li>Embedded and Server mode, Clustering support
</li><li>Strong security features
</li><li>Experimental native version (GCJ) and ODBC drivers
</li></ul>
80 81 82 83

<h3>Additional Features</h3>
<ul>
<li>Disk based or in-memory databases and tables, read-only database support, temporary tables
84 85 86 87 88 89
</li><li>Transaction support (serializable transaction isolation), 2-phase-commit
</li><li>Multiple connections, table level locking
</li><li>Cost based optimizer, using a genetic algorithm for complex queries, zero-administration
</li><li>Scrollable and updatable result set support, large result set, external result sorting, functions can return a result set
</li><li>Encrypted database (AES or XTEA), SHA-256 password encryption, encryption functions, SSL
</li></ul>
90 91 92 93

<h3>SQL Support</h3>
<ul>
<li>Compatibility modes for HSQLDB, MySQL and PostgreSQL
94 95 96 97 98 99 100 101 102 103
</li><li>Support for multiple schemas, information schema
</li><li>Referential integrity / foreign key constraints with cascade, check constraints
</li><li>Inner and outer joins, subqueries, read only views and inline views
</li><li>Triggers and Java functions / stored procedures
</li><li>Many built-in functions, including XML and lossless data compression
</li><li>Wide range of data types including large objects (BLOB/CLOB)
</li><li>Sequence and autoincrement columns, computed columns (can be used for function based indexes)
</li><li>ORDER BY, GROUP BY, HAVING, UNION, LIMIT, TOP
</li><li>Collation support, Users, Roles
</li></ul>
104 105 106 107

<h3>Security Features</h3>
<ul>
<li>User password authenticated uses SHA-256 and salt
108 109 110 111 112 113 114
</li><li>User passwords are never transmitted in plain text over the network (even when using insecure connections)
</li><li>All database files (including script files that can be used to backup data) can be encrypted using AES-256 and XTEA encryption algorithms
</li><li>The remote JDBC driver supports TCP/IP connections over SSL/TLS
</li><li>The built-in web server supports connections over SSL/TLS
</li><li>Passwords can be sent to the database using char arrays instead of Strings
</li><li>Includes a solution for the SQL injection problem
</li></ul>
115 116 117 118

<h3>Other Features and Tools</h3>
<ul>
<li>Small footprint (smaller than 1 MB), low memory requirements
119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134
</li><li>Multiple index types (b-tree, tree, hash, linear hash)
</li><li>Support for multi-dimensional indexes
</li><li>CSV file support
</li><li>Support for linked tables, and a built-in virtual 'range' table
</li><li>EXPLAIN PLAN support, sophisticated trace options
</li><li>Database closing can be delayed or disabled to improve the performance
</li><li>Web-based Console application (English, German, partially French and Spanish) with autocomplete
</li><li>The database can generate SQL script files
</li><li>Contains a recovery tool that can dump the contents of the data file
</li><li>Automatic re-compilation of prepared statements
</li><li>Uses a small number of database files, binary and text storage formats, graceful handling of low disk space situations
</li><li>Uses a checksum for each record and log entry for data integrity
</li><li>Well tested (high code coverage, randomized stress tests)
</li></ul>

<br /><a name="comparison"></a>
135 136 137 138 139 140
<h2>Comparison to Other Database Engines</h2>

<table><tr>
<th>Feature</th>
<th>H2</th>
<th>Derby</th>
141
<th>HSQLDB</th>
142 143 144 145 146 147 148
<th>MySQL</th>
<th>PostgreSQL</th>
</tr><tr>
<td>Embedded Mode (Java)</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
149 150 151 152 153 154
<td class="compareN">No</td>
<td class="compareN">No</td>
</tr><tr>
<td>Pure Java</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
155 156 157 158 159 160 161
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
</tr><tr>
<td>Performance (Embedded)</td>
<td class="compareY">Fast</td>
<td class="compareN">Slow</td>
162
<td class="compareY">Fast</td>
163 164 165 166 167 168
<td class="compareN">N/A</td>
<td class="compareN">N/A</td>
</tr><tr>
<td>Transaction Isolation</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
169
<td class="compareN">No</td>
170 171 172 173 174 175
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Cost Based Optimizer</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
176
<td class="compareN">No</td>
177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Clustering</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Encrypted Database</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
</tr><tr>
<td>Files per Database</td>
<td class="compareY">Few</td>
<td class="compareN">Many</td>
<td class="compareY">Few</td>
<td class="compareN">Many</td>
<td class="compareN">Many</td>
</tr><tr>
<td>Footprint (jar/dll size)</td>
202 203 204 205 206
<td>~ 1 MB</td>
<td>~ 2 MB</td>
<td>~ 600 KB</td>
<td>~ 4 MB</td>
<td>~ 6 MB</td>
207 208 209
</tr>
</table>

210 211 212 213 214 215
<h3>Derby and HSQLDB</h3>
After an unexpected process termination (for example power failure), H2 can recover safely and 
automatically without any user interaction. For Derby and HSQLDB, there are some manual steps required 
('Another instance of Derby may have already booted the database' / 
'The database is already in use by another process').

216 217 218 219 220 221
<h3>DaffodilDb and One$Db</h3>
It looks like the development of this database has stopped. The last release was February 2006.

<h3>McKoi</h3>
It looks like the development of this database has stopped. The last release was August 2004

222
<br /><a name="products_work_with"></a>
223 224 225 226 227
<h2>Products that Work with H2</h2>
<table>
<tr><th>Product</th><th>Description</th></tr>

    <tr>
228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245
        <td><a href="http://jackrabbit.apache.org">Apache Jackrabbit</a></td>
        <td>Open source implementation of the Java Content Repository API (JCR).</td>     
    </tr><tr>
        <td><a href="http://incubator.apache.org/openjpa">Apache OpenJPA</a></td>
        <td>Open source implementation of the Java Persistence API.</td>     
    </tr><tr>
        <td><a href="http://bmarks-portlet.sourceforge.net">Bookmarks Portlet</a></td>
        <td>JSR168 compliant bookmarks management portlet application.</td>
    </tr><tr>
        <td><a href="http://www.minq.se/products/dbvis">DbVisualizer</a></td>
        <td>Database tool.</td>
    </tr><tr>
        <td><a href="http://executequery.org">Execute Query</a></td>
        <td>Database utility written in Java.</td>     
    </tr><tr>
        <td><a href="http://www.goldenstudios.or.id">Golden T Studios</a></td>
        <td>Fun-to-play games with a simple interface.</td>
    </tr><tr>
246 247
        <td><a href="http://hibernate.org">Hibernate</a></td>
        <td>Relational Persistence for Idiomatic Java (O-R Mapping Tool)</td>
248 249 250
    </tr><tr>
        <td><a href="http://jamwiki.org">JAMWiki</a></td>
        <td>Java-based Wiki engine.</td>
251 252 253 254 255 256 257
    </tr><tr>
        <td><a href="http://www.jpox.org">JPOX</a></td>
        <td>Java Persistent Objects</td>
    </tr><tr>
        <td><a href="http://luntbuild.javaforge.com">Luntbuild</a></td>
        <td>Build automation and management tool</td>
    </tr><tr>
258 259
        <td><a href="http://www.jenkov.com/mrpersister/introduction.tmpl">Mr. Persister</a></td>
        <td>Simple, small and fast object relational mapping</td>
260 261 262 263 264 265 266 267 268
    </tr><tr>
        <td><a href="http://www.polepos.org">PolePosition</a></td>
        <td>Open source database benchmark.</td>
    </tr><tr>
        <td><a href="http://www.shellbook.com">Shellbook</a></td>
        <td>Desktop Publishing application.</td>
    </tr><tr>
        <td><a href="http://sql-workbench.net">SQL Workbench/J</a></td>
        <td>Free DBMS-independent SQL Tool.</td>     
269 270 271 272 273 274
    </tr><tr>
        <td><a href="http://squirrelsql.org">SQuirreL SQL Client</a></td>
        <td>Graphical tool to view the structure of a database, browse the data, issue SQL commands etc.</td>
    </tr><tr>
        <td><a href="http://dbcopyplugin.sf.net">SQuirreL DB Copy Plugin</a></td>
        <td>Tool to copy data from one database to another.</td>
275 276 277
    </tr><tr>
        <td><a href="http://www.streamcruncher.com">StreamCruncher</a></td>
        <td>Event (Stream) Processing Kernel.</td>     
278 279 280
    </tr><tr>
        <td><a href="http://www.webofweb.net">Web of Web</a></td>
        <td>Collaborative and realtime interactive media platform for the web.</td>
281 282 283
    </tr>
</table>

284
<br /><a name="why_java"></a>
285 286 287 288
<h2>Why Java</h2>
A few reasons using a Java database are:
<ul>
<li>Very simple to integrate in Java applications
289 290 291 292 293
</li><li>Support for many different platforms
</li><li>More secure than native applications (no buffer overflows)
</li><li>User defined functions (or triggers) run very fast
</li><li>Unicode support
</li></ul>
294
<p>
295 296 297 298 299 300
Some people think that Java is still too slow for low level operations, 
but this is not the case (not any more). In general, the code can be written a lot faster 
than using C or C++. Like that, it is possible to concentrate on improving the algorithms 
(that make the application faster) rather than porting the code and dealing with low 
level stuff (such as memory management or dealing with threads). 
Garbage collection is now probably faster than manual memory management.
301
</p><p>
302 303 304 305
A lot of features are already built in (for example Unicode, network libraries). 
It is very easy to write secure code because buffer overflows and such
problems can be detected very easily. Some features such as the reflection 
mechanism can be used for randomized testing.
306
</p><p>
307 308
Java is also future proof: A lot of companies support Java, and the 
open source support for Java is getting better as well (see GCJ).
309
</p><p>
310 311 312 313 314 315
This software does not rely on many Java libraries or other software, to
increase the portability and ease of use, and for performance reasons. For example, 
the encryption algorithms and many library functions are implemented in the database
instead of using the existing libraries. Libraries that are not available in open source
Java implementations (such as Swing) are not used or only used for specific features
(such as the SysTray library).
316
</p>
317

318
<br /><a name="connection_modes"></a>
319 320 321 322
<h2>Connection Modes</h2>
The following connection modes are supported:
<ul>
<li>Local connections using JDBC (embedded) 
323 324 325 326
</li><li>Remote connections using JDBC over TCP/IP (client/server)
</li><li>Remote connections using ODBC over TCP/IP (client/server)
</li><li>In-Memory databases (private and shared)
</li></ul>
327

328
<br /><a name="database_url"></a>
329
<h2>Database URL Overview</h2>
330
<p>
331 332
This database does support multiple connection modes and features when connecting to a database.
This is achieved using different database URLs. The settings in the URLs are not case sensitive.
333
</p>
334 335 336 337
<table><tr><th>Topic</th><th>URL Format and Examples</th></tr>
<tr>
  <td>Embedded (local) connection</td>
  <td>
338 339 340 341
    jdbc:h2:[file:][&lt;path&gt;]&lt;databaseName&gt;<br />
      jdbc:h2:test<br />
     jdbc:h2:file:/data/sample<br />
     jdbc:h2:file:C:/data/sample (Windows only)<br />
342 343 344 345 346 347 348 349 350
  </td>
</tr>
<tr>
  <td>In-Memory (private)</td>
  <td>jdbc:h2:mem:</td>
</tr>
<tr>
  <td>In-Memory (named)</td>
  <td>
351
    jdbc:h2:mem:&lt;databaseName&gt;<br />
352
    jdbc:h2:mem:test_mem
353 354 355 356 357
  </td>
</tr>
<tr>
  <td>Remote using TCP/IP</td>
  <td>
358 359
    jdbc:h2:tcp://&lt;server&gt;[&lt;port&gt;]/&lt;databaseName&gt;<br />
    jdbc:h2:tcp://localhost/test<br />
360 361 362 363 364 365
    jdbc:h2:tcp://dbserv:8084/sample
  </td>
</tr>
<tr>
  <td>Remote using SSL/TLS</td>
  <td>
366
    jdbc:h2:ssl://&lt;server&gt;[&lt;port&gt;]/&lt;databaseName&gt;<br />
367 368 369 370 371 372
    jdbc:h2:ssl://secureserv:8085/sample;
  </td>
</tr>
<tr>
  <td>Using Encrypted Files</td>
  <td>
373 374 375
    jdbc:h2:&lt;url&gt;;CIPHER=[AES][XTEA]<br />
    jdbc:h2:ssl://secureserv/testdb;CIPHER=AES<br />
    jdbc:h2:file:secure;CIPHER=XTEA<br />
376 377 378 379 380
  </td>
</tr>
<tr>
  <td>File Locking Methods</td>
  <td>
381 382 383
    jdbc:h2:&lt;url&gt;;FILE_LOCK={NO|FILE|SOCKET}<br />
    jdbc:h2:file:quickAndDirty;FILE_LOCK=NO<br />
    jdbc:h2:file:private;CIPHER=XTEA;FILE_LOCK=SOCKET<br />
384 385 386 387 388
  </td>
</tr>
<tr>
  <td>Only Open if it Already Exists</td>
  <td>
389 390
    jdbc:h2:&lt;url&gt;;IFEXISTS=TRUE<br />
    jdbc:h2:file:sample;IFEXISTS=TRUE<br />
391 392 393 394 395 396 397 398 399 400 401
  </td>
</tr>
<tr>
    <td>Don't Close the Database when the VM Exits</td>
    <td>
    jdbc:h2:&lt;url&gt;;DB_CLOSE_ON_EXIT=FALSE
    </td>
</tr>
<tr>
  <td>User Name and/or Password</td>
  <td>
402 403
    jdbc:h2:&lt;url&gt;[;USER=&lt;username&gt;][;PASSWORD=&lt;value&gt;]<br />
    jdbc:h2:file:sample;USER=sa;PASSWORD=123<br />
404 405 406 407 408
  </td>
</tr>
<tr>
  <td>Log Index Changes</td>
  <td>
409 410
    jdbc:h2:&lt;url&gt;;LOG=2<br />
    jdbc:h2:file:sample;LOG=2<br />
411 412 413 414 415
  </td>
</tr>
<tr>
  <td>Debug Trace Settings</td>
  <td>
416 417
    jdbc:h2:&lt;url&gt;;TRACE_LEVEL_FILE=&lt;level 0..3&gt;<br />
    jdbc:h2:file:sample;TRACE_LEVEL_FILE=3<br />
418 419 420 421 422
  </td>
</tr>
<tr>
  <td>Ignore Unknown Settings</td>
  <td>
423
    jdbc:h2:&lt;url&gt;;IGNORE_UNKNOWN_SETTINGS=TRUE<br />
424 425 426 427 428
  </td>
</tr>
<tr>
  <td>Changing Other Settings</td>
  <td>
429 430
    jdbc:h2:&lt;url&gt;;&lt;setting&gt;=&lt;value&gt;[;&lt;setting&gt;=&lt;value&gt;...]<br />
    jdbc:h2:file:sample;TRACE_LEVEL_SYSTEM_OUT=3<br />
431 432 433 434 435 436 437 438 439 440 441
  </td>
</tr>
</table>

<h3>Connecting to an Embedded (Local) Database</h3>
The database URL for connecting to a local database is <code>jdbc:h2:[file:][&lt;path&gt;]&lt;databaseName&gt;</code>.
The prefix <code>file:</code> is optional. If no or only a relative path is used, then the current working 
directory is used as a starting point. The case sensitivity of the path and database name depend on the 
operating system, however it is suggested to use lowercase letters only.

<h3>Memory-Only Databases</h3>
442
<p>
443 444 445
For certain use cases (for example: rapid prototyping, testing, high performance
operations, read-only databases), it may not be required to persist (changes to) the data at all. 
This database supports the memory-only mode, where the data is not persisted.
446
</p><p>
447 448 449 450
In some cases, only one connection to a memory-only database is required.
This means the database to be opened is private. In this case, the database URL is
<code>jdbc:h2:mem:</code> Opening two connections within the same virtual machine
means opening two different (private) databases.
451
</p><p>
452 453
Some times multiple connections to the same memory-only database are required.
In this case, the database URL must include a name. Example: <code>jdbc:h2:mem:db1</code>
454
</p><p>
455 456 457
It is also possible to open a memory-only database remotely using TCP/IP or SSL/TLS.
An example database URL is: <code>jdbc:h2:tcp://localhost/mem:db1</code>
(using private database remotely is also possible).
458
</p>
459

460
<br /><a name="file_encryption"></a>
461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477
<h2>Connecting to a Database with File Encryption</h2>
To use file encryption, it is required to specify the encryption algorithm (the 'cipher') 
and the file password. The algorithm needs to be specified using the connection parameter.
Two algorithms are supported: XTEA and AES. The file password is specified in the password field,
before the user password. A single space needs to be added between the file password 
and the user password; the file password itself may not contain spaces. File passwords
(as well as user passwords) are case sensitive. Here is an example to connect to a password
encrypted database:
<pre>
Class.forName("org.h2.Driver");
String url = "jdbc:h2:test;CIPHER=AES";
String user = "sa";
String pwds = "filepwd userpwd";
conn = DriverManager.
    getConnection(url, user, pwds);
</pre>

478
<br /><a name="database_file_locking"></a>
479
<h2>Database File Locking</h2>
480
<p>
481 482 483
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. 
484
</p><p>
485
The following file locking methods are implemented:
486
</p>
487 488 489
<ul>
<li>The default method is 'file' and uses a watchdog thread to
protect the database file. The watchdog reads the lock file each second. 
490
</li><li>The second method is 'socket' and opens a server socket. The socket method does 
491 492
not require reading the lock file every second. The socket method should only be used
if the database files are only accessed by the one (and always the same) computer.
493
</li><li>It is also possible to open the database without file locking;
494
in this case it is up to the application to protect the database files. 
495
</li></ul>
496 497 498 499 500 501 502 503 504 505 506 507 508 509
To open the database with a different file locking method, use the parameter 'FILE_LOCK'.
The following code opens the database with the 'socket' locking method:
<pre>
String url = "jdbc:h2:test;FILE_LOCK=SOCKET";
</pre>
The following code forces the database to not create a lock file at all. Please note that
this is unsafe as another process is able to open the same database, possibly leading to 
data corruption:
<pre>
String url = "jdbc:h2:test;FILE_LOCK=NO";
</pre>
For more information about the algorithms please see in Advanced Topics under 
File Locking Protocol.  

510
<br /><a name="database_only_if_exists"></a>
511 512 513 514 515 516 517 518 519 520 521 522
<h2>Opening a Database Only if it Already Exists</h2>
By default, when an application calls <code>DriverManager.getConnection(url,...)</code> 
and the database specified in the URL does not yet exist, a new (empty) database is created.
In some situations, it is better to restrict creating new database, and only open
the database if it already exists. This can be done by adding <code>;ifexists=true</code>
to the URL. In this case, if the database does not already exist, an exception is thrown when 
trying to connect. The connection only succeeds when the database already exists.
The complete URL may look like this:
<pre>
String url = "jdbc:h2:/data/sample;IFEXISTS=TRUE";
</pre>

523
<br /><a name="closing_the_database"></a>
524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553
<h2>Closing the Database</h2>

<h3>Delayed Database Closing</h3>
Usually, the database is closed when the last connection to it is closed. In some situations
this slows down the application, for example when it is not possible leave the connection open.
The automatic closing of the database can be delayed or disabled with the SQL statement 
SET DB_CLOSE_DELAY &lt;seconds&gt;. The seconds specifies the number of seconds to keep
a database open after the last connection to it was closed. For example the following statement
will keep the database open for 10 seconds:
<pre>
SET DB_CLOSE_DELAY 10
</pre>
The value -1 means the database is never closed automatically.
The value 0 is the default and means the database is closed when the last connection is closed.
This setting is persistent and can be set by an administrator only.
It is possible to set the value in the database URL: <code>jdbc:h2:test;DB_CLOSE_DELAY=10</code>.

<h3>Don't Close the Database when the VM Exits</h3>
By default, a database is closed when the last connection is closed. However, if it is never closed,
the database is closed when the virtual machine exits normally. This is done using a shutdown hook.
In some situations, the database should not be closed in this case, for example because the
database is still used at virtual machine shutdown (to store the shutdown process in the database for example).
In this case, the automatic closing of the database can be disabled. 
This can be done in the database URL. The first connection (the one that is opening the database) needs to 
set the option in the database URL (it is not possible to change the setting afterwards).
The database URL to disable database closing on exit is:
<pre>
String url = "jdbc:h2:test;DB_CLOSE_ON_EXIT=FALSE";
</pre>

554
<br /><a name="log_index_changes"></a>
555 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
<h2>Log Index Changes</h2>
Usually, changes to the index file are not logged for performance.
If the index file is corrupt or missing when opening a database, it is re-created from the data.
The index file can get corrupt when the database is not shut down correctly,
because of power failure or abnormal program termination.
In some situations, for example when using very large databases (over a few hundred MB),
re-creating the index file takes very long. 
In these situations it may be better to log changes to the index file,
so that recovery from a corrupted index file is fast.
To enable log index changes, add LOG=2 to the URL, as in jdbc:h2:test;LOG=2
This setting should be specified when connecting.
The update performance of the database will be reduced when using this option.

<h3>Ignore Unknown Settings</h3>
Some applications (for example OpenOffice.org Base) pass some additional parameters 
when connecting to the database. Why those parameters are passed is unknown.
The parameters PREFERDOSLIKELINEENDS and IGNOREDRIVERPRIVILEGES are such examples,
they are simply ignored to improve the compatibility with OpenOffice.org. If an application
passes other parameters when connecting to the database, usually the database throws an exception
saying the parameter is not supported. It is possible to ignored such parameters by adding
;IGNORE_UNKNOWN_SETTINGS=TRUE to the database URL. 

<h3>Changing Other Settings when Opening a Connection</h3>
In addition to the settings already described (cipher, file_lock, ifexists, user, password), 
other database settings can be passed in the database URL.
Adding <code>setting=value</code> at the end of an URL is the
same as executing the statement <code>SET setting value</code> just after
connecting. For a list of settings supported by this database please see the
SQL grammar documentation.

585
<br /><a name="multiple_connections"></a>
586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605
<h2>Multiple Connections</h2>

<h3>Opening Multiple Databases at the Same Time</h3>
An application can open multiple databases at the same time, including multiple
connections to the same database. The number of open database is only limited by the memory available.

<h3>Multiple Connections to the Same Database: Client/Server</h3>
 If you want to access the same database at the same time from different processes or computers,
 you need to use the client / server mode. In this case, one process acts as the server, and the
 other processes (that could reside on other computers as well) connect to the server via TCP/IP
 (or SSL/TLS over TCP/IP for improved security).
 
<h3>Multithreading Support</h3>
 This database is multithreading-safe. That means, if an application is multi-threaded, it does not need
 to worry about synchronizing the access to the database. Internally, most requests to the same database 
 are synchronized. That means an application can use multiple threads all accessing the same database
 at the same time, however if one thread executes a long running query, the other threads
 need to wait.
 
<h3>Locking, Lock-Timeout, Deadlocks</h3>
606
<p>
607 608 609 610 611 612
The database uses table level locks to give each connection a consistent state of the data.
There are two kinds of locks: read locks (shared locks) and write locks (exclusive locks).
If a connection wants to reads from a table, and there is no write lock on the table, 
then a read lock is added to the table. If there is a write lock, then this connection waits
for the other connection to release the lock. If connection cannot get a lock for a specified time,
then a lock timeout exception is thrown. 
613
</p><p>
614 615 616 617 618 619 620 621
Usually, SELECT statement will generate read locks. This includes subqueries. 
Statements that modify data use write locks. It is also possible to lock a table exclusively without modifying data, 
using the statement SELECT ... FOR UPDATE.
The statements COMMIT and ROLLBACK releases all open locks.
The commands SAVEPOINT and ROLLBACK TO SAVEPOINT don't affect locks.
The locks are also released when the autocommit mode changes, and for connections with 
autocommit set to true (this is the default), locks are released after each statement.
Here is an overview on what statements generate what type of lock:
622
</p>
623 624 625 626 627 628
<table><tr><th>Type of Lock</th><th>SQL Statement</th></tr>
<tr>
  <td>
    Read
  </td>
  <td>
629 630
    SELECT * FROM TEST<br />
    CALL SELECT MAX(ID) FROM TEST<br />
631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646
    SCRIPT
  </td>
</tr>
<tr>
  <td>
    Write
  </td>
  <td>
    SELECT * FROM TEST WHERE 1=0 FOR UPDATE
  </td>
</tr>
<tr>
  <td>
    Write
  </td>
  <td>
647 648 649
    INSERT INTO TEST VALUES(1, 'Hello')<br />
    INSERT INTO TEST SELECT * FROM TEST<br />
    UPDATE TEST SET NAME='Hi'<br />
650 651 652 653 654 655 656 657
    DELETE FROM TEST
  </td>
</tr>
<tr>
  <td>
    Write
  </td>
  <td>
658 659
    ALTER TABLE TEST ...<br />
    CREATE INDEX ... ON TEST ...<br />
660 661 662 663 664 665 666 667 668
    DROP INDEX ...
  </td>
</tr>
</table>
<p>
The number of seconds until a lock timeout exception is thrown can be
set separately for each connection using the SQL command SET LOCK_TIMEOUT &lt;milliseconds&gt;.
The initial lock timeout (that is the timeout used for new connections) can be set using the SQL command
SET DEFAULT_LOCK_TIMEOUT &lt;milliseconds&gt;. The default lock timeout is persistent.
669
</p>
670

671
<br /><a name="database_file_layout"></a>
672
<h2>Database File Layout</h2>
673
<p>
674 675 676 677 678 679 680
There are a number of files created for persistent databases. Other than some databases, 
not every table and/or index is stored in its own file. Instead, usually only the following files are created:
A data file, an index file, a log file, and a database lock file (exists only while the database is in use).
In addition to that, a file is created for each large object (CLOB/BLOB), a file for each linear index, 
and temporary files for large result sets. Then the command SCRIPT can create script files.
If the database trace option is enabled, trace files are created.
The following files can be created by the database:
681
</p>
682 683 684 685
<table><tr><th>File Name</th><th>Description</th><th>Number of Files</th></tr>
<tr><td>
    test.data.db
</td><td>
686 687
    Data file<br />
    Contains the data for all tables<br />
688 689 690 691 692 693 694
    Format: &lt;database&gt;.data.db
</td><td>
    1 per database
</td></tr>
<tr><td>
    test.index.db
</td><td>
695 696
    Index file<br />
    Contains the data for all (btree) indexes<br />
697 698 699 700 701 702 703
    Format: &lt;database&gt;.index.db
</td><td>
    1 per database
</td></tr>
<tr><td>
    test.0.log.db
</td><td>
704 705
    Log file<br />
    The log file is used for recovery<br />
706 707 708 709 710 711 712
    Format: &lt;database&gt;.&lt;id&gt;.log.db
</td><td>
    0 or more per database
</td></tr>
<tr><td>
    test.lock.db
</td><td>
713 714
    Database lock file<br />
    Exists only if the database is open<br />
715 716 717 718 719 720 721
    Format: &lt;database&gt;.lock.db
</td><td>
    1 per database
</td></tr>
<tr><td>
    test.trace.db
</td><td>
722 723 724
    Trace file<br />
    Contains trace information<br />
    Format: &lt;database&gt;.trace.db<br />
725 726 727 728 729 730 731
    If the file is too big, it is renamed to &lt;database&gt;.trace.db.old
</td><td>
    1 per database
</td></tr>
<tr><td>
    test.14.15.lob.db
</td><td>
732 733
    Large object<br />
    Contains the data for BLOB or CLOB<br />
734 735 736 737 738 739 740
    Format: &lt;database&gt;.&lt;tableid&gt;.&lt;id&gt;.lob.db
</td><td>
    1 per object
</td></tr>
<tr><td>
    test.123.temp.db
</td><td>
741 742
    Temporary file<br />
    Contains a temporary blob or a large result set<br />
743 744 745 746 747 748 749
    Format: &lt;database&gt;.&lt;session id&gt;.&lt;object id&gt;.temp.db
</td><td>
    1 per object
</td></tr>
<tr><td>
    test.7.hash.db
</td><td>
750 751
    Hash index file<br />
    Contains the data for a linear hash index<br />
752 753 754 755 756 757 758 759
    Format: &lt;database&gt;.&lt;object id&gt;.hash.db
</td><td>
    1 per linear hash index
</td></tr>
</table>

<h3>Moving and Renaming Database Files</h3>
<p>
760 761
Database name and location are not stored inside the database names.
</p><p>
762 763
While a database is closed, the files can be moved to another directory, and they can be renamed 
as well (as long as all files start with the same name).
764
</p><p>
765 766
As there is no platform specific data in the files, they can be moved to other operating systems
without problems.
767
</p>
768 769

<h3>Backup</h3>
770
<p>
771 772 773
When the database is closed, it is possible to backup the database files. Please note that index
files do not need to be backed up, because they contain redundant data, and will be recreated
automatically if they don't exist.
774
</p><p>
775
To backup data while the database is running, the SQL command SCRIPT can be used.
776
</p>
777

778
<br /><a name="logging_recovery"></a>
779
<h2>Logging and Recovery</h2>
780
<p>
781 782 783 784 785
Whenever data is modified in the database and those changes are committed, the changes are logged 
to disk (except for in-memory objects). The changes to the data file itself are usually written 
later on, to optimize disk access. If there is a power failure, the data and index files are not up-to-date.
But because the changes are in the log file, the next time the database is opened, the changes that are
in the log file are re-applied automatically.
786
</p><p>
787 788
Please note that index file updates are not logged by default. If the database is opened and recovery is required,
the index file is rebuilt from scratch.
789
</p><p>
790 791 792
There is usually only one log file per database. This file grows until the database is closed successfully, 
and is then deleted. Or, if the file gets too big, the database switches to another log file (with a higher id). 
It is possible to force the log switching by using the CHECKPOINT command.
793
</p><p>
794 795 796 797 798 799
If the database file is corrupted, because the checksum of a record does not match (for example, if the
file was edited with another application), the database can be opened in recovery mode. In this case,
errors in the database are logged but not thrown. The database should be backed up to a script
and re-built as soon as possible. To open the database in the recovery mode, use a database URL
must contain RECOVER=1, as in jdbc:h2:test;RECOVER=1. Indexes are rebuilt in this case, and
the summary (object allocation table) is not read in this case, so opening the database takes longer.
800
</p>
801

802
<br /><a name="compatibility_modes"></a>
803
<h2>Compatibility Modes</h2>
804
<p>
805 806 807 808 809 810 811 812
All database engines behave a little bit different. For certain features, 
this database can emulate the behavior of specific databases. Not all features or differences of those
databases are implemented. Currently, this feature is mainly used for randomized comparative testing 
(where random statements are executed against multiple databases and the results are compared).
The mode can be changed by specifying the mode in the database URL, or using the SQL statement SET MODE.
To use the HSQLDB mode, you can use the database URL <code>jdbc:h2:test;MODE=HSQLDB</code>
or the SQL statement <code>SET MODE HSQLDB</code>. 
Here is the list of currently supported modes and the difference to the regular mode:
813
</p>
814 815 816 817 818
<table>
<tr><th>Mode</th><th>Differences</th></tr>
<tr><td>
  PostgreSQL
</td><td>
819
  Concatenation of a NULL with another value results in NULL.
820 821 822 823 824 825
  Usually, the NULL is treated as an empty string if only one of the operators is NULL,
  and NULL is only returned if both values are NULL.
</td></tr>
<tr><td>
  MySQL
</td><td>
826
  When inserting data, if a column is defined to be NOT NULL and NULL is inserted,
827 828 829 830 831 832 833 834 835 836 837 838
  then a 0 (or empty string, or the current timestamp for timestamp columns) value is used.
  Usually, this operation is not allowed and an exception is thrown.
</td></tr>
<tr><td>
  HSQLDB
</td><td>
  When converting the scale of decimal data, the number is only converted if the new scale is
  smaller then current scale.
  Usually, the scale is converted and 0s are added if required.
</td></tr>
</table>

839
<br /><a name="trace_options"></a>
840 841 842 843 844
<h2>Using the Trace Options</h2>
To find problems in an application, it is sometimes good to see what database operations 
where executed. This database offers the following trace features:
<ul>
<li>Trace to System.out and/or a file
845 846 847 848 849
</li><li>Support for trace levels OFF, ERROR, INFO, and DEBUG
</li><li>The maximum size of the trace file can be set
</li><li>The Java code generation is possible
</li><li>Trace can be enabled at runtime by manually creating a file
</li></ul>
850 851 852 853 854

<h3>Trace Options</h3>
The simplest way to enable the trace option is setting it in the database URL.
There are two settings, one for System.out (TRACE_LEVEL_SYSTEM_OUT) tracing, 
and one for file tracing (TRACE_LEVEL_FILE). 
855
The trace levels are 0 for OFF, 1 for ERROR (the default), 2 for INFO and 3 for DEBUG.
856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907
A database URL with both levels set to DEBUG is:
<pre>
jdbc:h2:test;TRACE_LEVEL_FILE=3;TRACE_LEVEL_SYSTEM_OUT=3
</pre>
The trace level can be changed at runtime by executing the SQL command
<code>SET TRACE_LEVEL_SYSTEM_OUT level</code> (for System.out tracing)
or <code>SET TRACE_LEVEL_FILE level</code> (for file tracing).
Example:
<pre>
SET TRACE_LEVEL_SYSTEM_OUT 3
</pre>

<h3>Setting the Maximum Size of the Trace File</h3>
When using a high trace level, the trace file can get very big quickly.
The size of the file can be limited by executing the SQL statement 
<code>SET TRACE_MAX_FILE_SIZE maximumFileSizeInMB</code>.
If the log file exceeds the limit, the file is renamed to .old and a new file is created.
If another .old file exists, it is deleted.
The default setting is 16 MB. Example:
<pre>
SET TRACE_MAX_FILE_SIZE 1
</pre>

<h3>Java Code Generation</h3>
When setting the trace level to INFO or DEBUG, Java source code is generated as well, so that
problem can be reproduced more easily. The trace file looks like this:

<pre>
...
12-20 20:58:09 jdbc[0]: 
/**/dbMeta3.getURL();
12-20 20:58:09 jdbc[0]: 
/**/dbMeta3.getTables(null, "", null, new String[]{"TABLE", "VIEW"});
...
</pre>

You need to filter out the lines without /**/ to get the Java source code.
In Windows, a simple way to do that is:
<pre>
find "**" test.trace.db > Trace.java
</pre>
Afterwards, you need to complete the file Trace.java before it can be compiled, for example with:
<pre>
import java.sql.*;
public class Trace { public static void main(String[]a)throws Exception {
Class.forName("org.h2.Driver");
...
}}
</pre>
Also, the user name and password needs to be set, because they are not listed in the trace file.

<h3>Enabling the Trace Option at Runtime by Manually Creating a File</h3>
908
<p>
909 910 911 912 913 914
Sometimes, you can't or don't want to change the application or database URL.
There is still a way to enable the trace mode in these cases, even at runtime (while
the database connection is open). You only need to create a special file in the directory 
where the database files are stored.
The database engine checks every 4 seconds if this file exists (only while executing a statement).
The file name is the database name plus '.trace.db.start'. 
915
</p><p>
916 917 918 919 920 921
Example: if a database is called 'test', then the file to start tracing is 'test.trace.db.start'.
The database engine tries to delete this file when it detects it.
If trace is enabled using the start file, the trace level is not persistent to the database, and
trace is switched back to the level that was set before when connecting to the database.
However, if the start file is read only, the database engine cannot delete the file and
will always enable the trace mode when connecting.
922
</p>
923

924
<br /><a name="read_only"></a>
925 926 927 928 929 930 931 932 933 934
<h2>Read Only Databases</h2>
If the database files are read-only, then the database is read-only as well.
It is not possible to create new tables, add or modify data in this database.
Only SELECT statements are allowed.
To create a read-only database, close the database so that the log file is deleted.
Then, make the database files read-only using the operating system.
When you open the database now, it is read-only.
There are two ways an application can find out a database is read-only:
By calling Connection.isReadOnly() or by executing the SQL statement CALL READONLY().

935
<br /><a name="storage_formats"></a>
936 937 938 939 940 941 942 943 944
<h2>Binary and Text Storage Formats</h2>
This database engine supports both binary and text storage formats. 
The binary format is faster, but the text storage format can be useful as well,
for example to debug the database engine.
If a database already exists, the storage format is recognized automatically.
New databases are created in the binary storage format by default.
To create a new database in the text storage format, the database URL must contain
the parameter STORAGE=TEXT. Example URL: jdbc:h2:test;STORAGE=TEXT

945
<br /><a name="low_disk_space"></a>
946
<h2>Graceful Handling of Low Disk Space Situations</h2>
947
<p>
948 949 950 951 952 953 954 955
The database is able to deal with situations where the disk space available is running low.
Whenever the database starts, an 'emergency space' file is created (size is 1 MB),
and if there is no more space available, the file will shrink. If the space available
is lower than 128 KB, the database will go into a special read only mode, where
writing operations are no longer allowed: All writing operations will throw the
exception 'No disk space available' from this point on. To go back to the normal operating
mode, all connections to the database need to be closed first, and space needs to
be freed up.
956
</p><p>
957 958 959 960 961 962 963
It is possible to install a database event listener to detect low disk space situations early on
(when only 1 MB if space is available). To do this, use the SQL statement
SET DATABASE_EVENT_LISTENER. 
The listener can also be set at connection time, using an URL of the form
jdbc:h2:test;DATABASE_EVENT_LISTENER='com.acme.DbListener'
(the quotes around the class name are required).
See also the DatabaseEventListener API. 
964
</p>
965 966 967 968 969 970

<h3>Opening a Corrupted Database</h3>
If a database can not be opened because the boot info (the SQL script that is run at startup)
is corrupted, then the database can be opened by specifying a database event listener. 
The exceptions are logged, but opening the database will continue.

971
<br /><a name="computed_columns"></a>
972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992
<h2>Computed Columns / Function Based Index</h2>
Function indexes are not directly supported by this database, but they can be easily emulated
by using computed columns. For example, if an index on the upper-case version of
a column is required, just create a computed column with the upper-case version of the original column,
and index this column:
<pre>
CREATE TABLE ADDRESS(
  ID INT PRIMARY KEY, 
  NAME VARCHAR, 
  UPPER_NAME VARCHAR AS UPPER(NAME)
);
CREATE INDEX IDX_U_NAME ON ADDRESS(UPPER_NAME);
</pre>
When inserting data, it is not required (better: not allowed) to specify a value for the upper-case
version of the column, because the value is generated. But you can use the
column when querying the table:
<pre>
INSERT INTO ADDRESS(ID, NAME) VALUES(1, 'Miller');
SELECT * FROM ADDRESS WHERE UPPER_NAME='MILLER';
</pre>

993
<br /><a name="multi_dimensional"></a>
994
<h2>Multi-Dimensional Indexes</h2>
995
<p>
996 997 998 999 1000
A tool is provided to execute efficient multi-dimension (spatial) range queries.
This database does not support a specialized spatial index (R-Tree or similar).
Instead, the B-Tree index is used. For each record, the multi-dimensional key
is converted (mapped) to a single dimensional (scalar) value. 
This value specifies the location on a space-filling curve.
1001
</p><p>
1002 1003 1004 1005
Currently, Z-order (also called N-order or Morton-order) is used; 
Hilbert curve could also be used, but the implementation is more complex. 
The algorithm to convert the multi-dimensional value is called bit-interleaving. 
The scalar value is indexed using a B-Tree index (usually using a computed column).    
1006
</p><p>
1007 1008 1009 1010 1011 1012 1013
The method can result in a drastic performance improvement 
over just using an index on the first column. Depending on the 
data and number of dimensions, the improvement is usually higher than factor 5.
The tool generates a SQL query from a specified multi-dimensional range.
The method used is not database dependent, and the tool can easily be ported to other databases.
For an example how to use the tool, please have a look at the sample code provided
in TestMultiDimension.java.
1014
</p>
1015

1016
<br /><a name="passwords"></a>
1017 1018 1019
<h2>Using Passwords</h2>

<h3>Using Secure Passwords</h3>
1020
<p>
1021 1022 1023 1024 1025
Remember that weak passwords can be broken no matter of the encryption and security protocol.
Don't use passwords that can be found in a dictionary. Also appending numbers does not make them
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. 
Example:
1026
</p><p>
1027
i'sE2rtPiUKtT (it's easy to remember this password if you know the trick)
1028
</p>
1029 1030

<h3>Passwords: Using Char Arrays instead of Strings</h3>
1031
<p>
1032 1033 1034 1035 1036 1037
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 (because not enough main memory is available).
1038
</p><p>
1039 1040 1041 1042
An attacker might have access to the swap file of the operating system. 
It is therefore a good idea to use char arrays instead of Strings to store passwords.
Char arrays can be cleared (filled with zeros) after use, and therefore the
password will not be stored in the swap file.
1043
</p><p>
1044 1045
This database supports using char arrays instead of String to pass user and file passwords.
The following code can be used to do that:
1046
</p>
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
<pre>
Class.forName("org.h2.Driver");
String url = "jdbc:h2:simple";
String user = "sam";
char[] password = 
{'t','i','a','S','&amp;',E','t','r','p'};
Properties prop = new Properties();
prop.setProperty("user", user);
prop.put("password", password);
Connection conn = null;
try {
    conn = DriverManager.
      getConnection(url, prop);
} finally {
    Arrays.fill(password, 0);
}
</pre>
In this example, the password is hard code in the application, which is not secure of course. 
However, Java Swing supports a way to get passwords using a char array (JPasswordField).

<h3>Passing the User Name and/or Password in the URL</h3>
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.

1080
<br /><a name="user_defined_functions"></a>
1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098
<h2>User Defined Functions and Stored Procedures</h2>

In addition to the built-in functions, this database supports user defined Java functions.
In this database, Java functions can be used as stored procedures as well.
A function must be declared (registered) before it can be used.
Only static Java methods are supported; both the class and the method must be public.
Example Java method:
<pre>
package org.h2.samples;
...
public class Function {
    public static boolean isPrime(int value) {
        return new BigInteger(String.valueOf(value)).isProbablePrime(100);
    }
}
</pre>
The Java function must be registered in the database by calling CREATE ALIAS:
<pre>
1099
CREATE ALIAS IS_PRIME FOR "org.h2.samples.Function.isPrime"
1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160
</pre>
For a complete sample application, see src/test/org/h2/samples/Function.java.

<h3>Function Data Type Mapping</h3>
Functions that accept non-nullable parameters such as 'int' will not be called if one of those parameters is NULL.
In this case, the value NULL is used as the result. If the function should be called in this case, you need
to use 'java.lang.Integer' instead of 'int'.

<h3>Functions that require a Connection</h3>
If the first parameter in a Java function is a java.sql.Connection, then the connection
to database is provided. This connection does not need to be closed before returning.

<h3>Functions throwing an Exception</h3>
If a function throws an Exception, then the current statement is rolled back 
and the exception is thrown to the application.

<h3>Functions returning a Result Set</h3>
Functions may returns a result set. Such a function can be called with the CALL statement:
<pre>
public static ResultSet query(Connection conn, String sql) throws SQLException {
    return conn.createStatement().executeQuery(sql);
}
    
CREATE ALIAS QUERY FOR "org.h2.samples.Function.query";
CALL QUERY('SELECT * FROM TEST');
</pre>

<h3>Using SimpleResultSet</h3>
A function that returns a result set can create this result set from scratch using the SimpleResultSet tool:
<pre>
import org.h2.tools.SimpleResultSet;
...
public static ResultSet simpleResultSet() throws SQLException {
    SimpleResultSet rs = new SimpleResultSet();
    rs.addColumn("ID", Types.INTEGER, 10, 0);
    rs.addColumn("NAME", Types.VARCHAR, 255, 0);
    rs.addRow(new Object[] { new Integer(0), "Hello" });
    rs.addRow(new Object[] { new Integer(1), "World" });
    return rs;
}    

CREATE ALIAS SIMPLE FOR "org.h2.samples.Function.simpleResultSet";
CALL SIMPLE();
</pre>

<h3>Using a Function as a Table</h3>
A function returning a result set can be like a table.
However, in this case the function is called at least twice:
First while parsing the statement to collect the column names 
(with parameters set to null where not known at compile time).
And then, while executing the statement to get the data (may be repeatedly if this is a join).
If the function is called just to get the column list, the URL of the connection passed to the function is
jdbc:columnlist:connection. Otherwise, the URL of the connection is jdbc:default:connection.
<pre>
public static ResultSet getMatrix(Integer id) throws SQLException {
    SimpleResultSet rs = new SimpleResultSet();
    rs.addColumn("X", Types.INTEGER, 10, 0);
    rs.addColumn("Y", Types.INTEGER, 10, 0);
    if(id == null) {
        return rs;
    }
1161 1162
    for(int x = 0; x &lt; id.intValue(); x++) {
        for(int y = 0; y &lt; id.intValue(); y++) {
1163 1164 1165 1166 1167 1168 1169 1170 1171 1172
            rs.addRow(new Object[] { new Integer(x), new Integer(y) });
        }
      }
    return rs;
}    

CREATE ALIAS MATRIX FOR "org.h2.samples.Function.getMatrix";
SELECT * FROM MATRIX(3) WHERE X>0;
</pre>

1173
<br /><a name="triggers"></a>
1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199
<h2>Triggers</h2>
This database supports Java triggers that are called before or after a row is updated, inserted or deleted.
Triggers can be used for complex consistency checks, or to update related data in the database.
It is also possible to use triggers to simulate materialized views.
For a complete sample application, see src/test/org/h2/samples/TriggerSample.java.
A Java trigger must implement the interface org.h2.api.Trigger:
<pre>
import org.h2.api.Trigger;
...
public class TriggerSample implements Trigger {
    public void init(String triggerName, String tableName) {
    }
    public void fire(Connection conn, 
            Object[] oldRow, Object[] newRow) 
            throws SQLException {
    }
}
</pre>
The connection can be used to query or update data in other tables.
The trigger then needs to be defined in the database:
<pre>
CREATE TRIGGER INV_INS AFTER INSERT ON INVOICE 
  FOR EACH ROW CALL "org.h2.samples.TriggerSample"
</pre>
The trigger can be used to veto a change, by throwing a SQL Exception.

1200
<br /><a name="compacting"></a>
1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220
<h2>Compacting a Database</h2>
Empty space in the database file is re-used automatically. 
To re-build the indexes, the most simple way is to delete the .index.db file
while the database is closed. However in some situations (for example after deleting 
a lot of data in a database), one sometimes wants to shrink the size of the database 
(compact a database). Here is a sample function to do this:
<pre>
public static void compact(String dir, String dbName,
        String user, String password) throws Exception
    String url = "jdbc:h2:" + dbName;
    String script = "test.sql";
    Backup.execute(url, user, password, script);
    DeleteDbFiles.execute(dir, dbName);
    RunScript.execute(url, user, password, script);
}
</pre>
See also the sample application org.h2.samples.Compact.
The commands SCRIPT / RUNSCRIPT can be used as well to create the a backup
of a database and re-build the database from the script.

1221
<br /><a name="cache_settings"></a>
1222 1223 1224 1225 1226 1227 1228
<h2>Cache Settings</h2>
<p>
The database keeps most frequently used data and index pages in the main memory.
The amount of memory used for caching can be changed using the setting 
CACHE_SIZE. This setting can be set in the database connection URL 
(jdbc:h2:test;CACHE_SIZE=200000), or it can be changed at runtime using
SET CACHE_SIZE size.
1229
</p><p>
1230 1231 1232
This database supports two cache page replacement algorithms: LRU (the default) and
2Q. For LRU, the pages that were least frequently used are removed from the
cache if it becomes full. The 2Q algorithm is a bit more complicated, basically two 
1233
queues are used. The 2Q algorithm is more resistant to table scans, however the overhead
1234 1235 1236
is a bit higher compared to the LRU. To use the cache algorithm 2Q, use a database URL
of the form jdbc:h2:test;CACHE_TYPE=TQ. The cache algorithm can not be changed
once the database is open.
1237
</p><p>
1238 1239 1240 1241 1242 1243
To get information about page reads and writes, and the current caching algorithm in use,
call SELECT * FROM INFORMATION_SCHEMA.SETTINGS. The number of pages read / written
is listed for the data and index file.
</p>

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