features.html 62.7 KB
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 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 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 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 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 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 554 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 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 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 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 813 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 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 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 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 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 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 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423 1424 1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445 1446 1447 1448 1449 1450 1451 1452 1453 1454 1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466 1467 1468 1469 1470 1471 1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494 1495 1496 1497 1498 1499 1500 1501 1502 1503 1504 1505 1506 1507 1508 1509 1510 1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539 1540 1541 1542 1543 1544 1545 1546 1547 1548 1549 1550 1551 1552 1553 1554 1555 1556 1557 1558 1559 1560 1561 1562 1563 1564 1565 1566 1567 1568 1569 1570 1571 1572 1573 1574 1575 1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591 1592 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602 1603 1604 1605 1606 1607 1608 1609 1610 1611 1612 1613 1614 1615 1616 1617 1618 1619 1620 1621 1622 1623 1624 1625 1626 1627 1628 1629 1630 1631 1632 1633 1634 1635 1636 1637 1638 1639 1640 1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 1651 1652 1653 1654 1655 1656 1657 1658 1659 1660 1661 1662 1663 1664
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Strict//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd">
<!--
Copyright 2004-2008 H2 Group. Multiple-Licensed under the H2 License, Version 1.0,
and under the Eclipse Public License, Version 1.0
(http://h2database.com/html/license.html).
Initial Developer: H2 Group
-->
<html xmlns="http://www.w3.org/1999/xhtml" lang="en" xml:lang="en">
<head><meta http-equiv="Content-Type" content="text/html;charset=utf-8" /><title>
Features
</title><link rel="stylesheet" type="text/css" href="stylesheet.css" />
<!-- [search] { -->
<script type="text/javascript" src="navigation.js"></script>
</head><body onload="frameMe();">
<table class="content"><tr class="content"><td class="content"><div class="contentDiv">
<!-- } -->

<h1>Features</h1>

<a href="#feature_list">
    Feature List</a><br />
<a href="#limitations">
    Limitations</a><br />
<a href="#comparison">
    Comparison to Other Database Engines</a><br />
<a href="#products_work_with">
    H2 in Use</a><br />
<a href="#connection_modes">
    Connection Modes</a><br />
<a href="#database_url">
    Database URL Overview</a><br />
<a href="#embedded_databases">
    Connecting to an Embedded (Local) Database</a><br />
<a href="#memory_only_databases">
    Memory-Only Databases</a><br />
<a href="#file_encryption">
    Connecting to a Database with File Encryption</a><br />
<a href="#database_file_locking">
    Database File Locking</a><br />
<a href="#database_only_if_exists">
    Opening a Database Only if it Already Exists</a><br />
<a href="#closing_the_database">
    Closing the Database</a><br />
<a href="#ignore_unknown_settings">
    Ignore Unknown Settings</a><br />
<a href="#other_settings">
    Changing Other Settings when Opening a Connection</a><br />
<a href="#log_index_changes">
    Log Index Changes</a><br />
<a href="#custom_access_mode">
    Custom File Access Mode</a><br />
<a href="#multiple_connections">
    Multiple Connections</a><br />
<a href="#database_file_layout">
    Database File Layout</a><br />
<a href="#logging_recovery">
    Logging and Recovery</a><br />
<a href="#compatibility">
    Compatibility</a><br />
<a href="#auto_reconnect">
    Auto-Reconnect</a><br />
<a href="#auto_mixed_mode">
    Automatic Mixed Mode</a><br />
<a href="#trace_options">
    Using the Trace Options</a><br />
<a href="#other_logging">
    Using Other Logging APIs</a><br />
<a href="#read_only">
    Read Only Databases</a><br />
<a href="#database_in_zip">
    Read Only Databases in Zip or Jar File</a><br />
<a href="#low_disk_space">
    Graceful Handling of Low Disk Space Situations</a><br />
<a href="#computed_columns">
    Computed Columns / Function Based Index</a><br />
<a href="#multi_dimensional">
    Multi-Dimensional Indexes</a><br />
<a href="#passwords">
    Using Passwords</a><br />
<a href="#user_defined_functions">
    User-Defined Functions and Stored Procedures</a><br />
<a href="#triggers">
    Triggers</a><br />
<a href="#compacting">
    Compacting a Database</a><br />
<a href="#cache_settings">
    Cache Settings</a><br />

<br /><a name="feature_list"></a>
<h2>Feature List</h2>
<h3>Main Features</h3>
<ul>
<li>Very fast database engine
</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>The PostgreSQL ODBC driver can be used
</li><li>Multi version concurrency
</li></ul>

<h3>Additional Features</h3>
<ul>
<li>Disk based or in-memory databases and tables, read-only database support, temporary tables
</li><li>Transaction support (read committed and 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>

<h3>SQL Support</h3>
<ul>
<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) and arrays
</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><li>Compatibility modes for IBM DB2, Apache Derby, HSQLDB, MS SQL Server, MySQL, Oracle, and PostgreSQL.
</li></ul>

<h3>Security Features</h3>
<ul>
<li>Includes a solution for the SQL injection problem
</li><li>User password authenticated uses SHA-256 and salt
</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></ul>

<h3>Other Features and Tools</h3>
<ul>
<li>Small footprint (smaller than 1 MB), low memory requirements
</li><li>Multiple index types (b-tree, tree, hash)
</li><li>Support for multi-dimensional indexes
</li><li>CSV (comma separated values) 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>Support for variables (for example to calculate running totals)
</li><li>Automatic re-compilation of prepared statements
</li><li>Uses a small number of database files
</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="limitations"></a>
<h2>Limitations</h2>
<p>
For the list of limitations, please have a look at the road map page at:
<a href="http://www.h2database.com/html/roadmap.html">
http://www.h2database.com/html/roadmap.html
</a>
</p>

<br /><a name="comparison"></a>
<h2>Comparison to Other Database Engines</h2>

<table><tr>
<th>Feature</th>
<th>H2</th>
<th>Derby</th>
<th>HSQLDB</th>
<th>MySQL</th>
<th>PostgreSQL</th>
</tr><tr>
<td>Pure Java</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
</tr><tr>
<td>Embedded Mode (Java)</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<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>
<td class="compareY">Fast</td>
<td class="compareN">N/A</td>
<td class="compareN">N/A</td>
</tr><tr>
<td>In-Memory Mode</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
</tr><tr>
<td>Transaction Isolation</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<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>
<td class="compareN">No</td>
<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>Linked Tables</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareY">Partially *1</td>
<td class="compareY">Partially *2</td>
<td class="compareN">No</td>
</tr><tr>
<td>ODBC Driver</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>Fulltext Search</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>User-Defined Datatypes</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>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>Table Level Locking</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Row Level Locking</td>
<td class="compareY">Yes *9</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Multi Version Concurrency</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Role Based Security</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes *3</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Updatable Result Sets</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes *7</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Sequences</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Limit and Offset</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Temporary Tables</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes *4</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Information Schema</td>
<td class="compareY">Yes</td>
<td class="compareY">No *8</td>
<td class="compareY">No *8</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
</tr><tr>
<td>Computed Columns</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
<td class="compareN">No</td>
<td class="compareY">Yes *6</td>
</tr><tr>
<td>Case Insensitive Columns</td>
<td class="compareY">Yes</td>
<td class="compareN">No</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes</td>
<td class="compareY">Yes *6</td>
</tr><tr>
<td>Custom Aggregate Functions</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>Footprint (jar/dll size)</td>
<td>~1 MB *5</td>
<td>~2 MB</td>
<td>~600 KB</td>
<td>~4 MB</td>
<td>~6 MB</td>
</tr>
</table>
<p>
*1 HSQLDB supports text tables.<br />
*2 MySQL supports linked MySQL tables under the name 'federated tables'.<br />
*3 Derby support for roles based security and password checking as an option.<br />
*4 Derby only supports global temporary tables.<br />
*5 The default H2 jar file contains debug information, jar files for other databases do not.<br />
*6 PostgreSQL supports functional indexes.<br />
*7 Derby only supports updatable result sets if the query is not sorted.<br />
*8 Derby and HSQLDB don't support standard compliant information schema tables.
*9 H2 supports row level locks when using multi version concurrency.
</p>

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

<h3>DaffodilDb and One$Db</h3>
<p>
It looks like the development of this database has stopped. The last release was February 2006.
</p>

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

<br /><a name="products_work_with"></a>
<h2>H2 in Use</h2>
<p>
For a list of applications that work with or use H2, see:
<a href="links.html">Links</a>.
</p>

<br /><a name="connection_modes"></a>
<h2>Connection Modes</h2>
<p>
The following connection modes are supported:
</p>
<ul>
<li>Embedded mode (local connections using JDBC)
</li><li>Remote mode (remote connections using JDBC or ODBC over TCP/IP)
</li><li>Mixed mode (local and remote connections at the same time)
</li></ul>

<h3>Embedded Mode</h3>
<p>
In embedded mode, an application opens a database from within the same JVM using JDBC.
This is the fastest and easiest connection mode.
The disadvantage is that a database may only be open in one virtual machine (and class loader) at any time.
As in all modes, both persistent and in-memory databases are supported.
There is no limit on the number of database open concurrently,
or on the number of open connections.
</p>
<img src="images/connection-mode-embedded.png"
    alt="The database is embedded in the application" />

<h3>Remote Mode</h3>
<p>
When using the remote mode (sometimes called server mode or client/server mode), an application opens a
database remotely using the JDBC or ODBC API. A server needs to be started within the same
or another virtual machine (or on another computer).
Many applications can connect to the same database at the same time.
The remote mode is slower than the embedded mode, because all data
is transferred over TCP/IP.
As in all modes, both persistent and in-memory databases are supported.
There is no limit on the number of database open concurrently,
or on the number of open connections.
</p>
<img src="images/connection-mode-remote.png"
    alt="The database is running in a server; the application connects to the server" />

<h3>Mixed Mode</h3>
<p>
The mixed mode is a combination of the embedded and the remote mode.
The main application connects to a database in embedded mode, but also starts
a server so that other applications (running in different virtual machines) can
concurrently access the same data. The embedded connections are as fast as if
the database is used in just the embedded mode, while the remote
connections are a bit slower.
</p>
<img src="images/connection-mode-mixed.png"
    alt="The database and the server is running inside the application; another application connects remotely" />

<br /><a name="database_url"></a>
<h2>Database URL Overview</h2>
<p>
This database supports multiple connection modes and connection settings.
This is achieved using different database URLs. Settings in the URLs are not case sensitive.
</p>
<table><tr><th>Topic</th><th>URL Format and Examples</th></tr>
<tr>
  <td><a href="#embedded_databases">Embedded (local) connection</a></td>
  <td>
    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 />
  </td>
</tr>
<tr>
  <td><a href="#memory_only_databases">In-Memory (private)</a></td>
  <td>jdbc:h2:mem:</td>
</tr>
<tr>
  <td><a href="#memory_only_databases">In-Memory (named)</a></td>
  <td>
    jdbc:h2:mem:&lt;databaseName&gt;<br />
    jdbc:h2:mem:test_mem
  </td>
</tr>
<tr>
  <td><a href="tutorial.html#using_server">Remote using TCP/IP</a></td>
  <td>
    jdbc:h2:tcp://&lt;server&gt;[:&lt;port&gt;]/&lt;databaseName&gt;<br />
    jdbc:h2:tcp://localhost/~/test<br />
    jdbc:h2:tcp://dbserv:8084/~/sample
  </td>
</tr>
<tr>
  <td><a href="advanced.html#ssl_tls_connections">Remote using SSL/TLS</a></td>
  <td>
    jdbc:h2:ssl://&lt;server&gt;[:&lt;port&gt;]/&lt;databaseName&gt;<br />
    jdbc:h2:ssl://secureserv:8085/~/sample;
  </td>
</tr>
<tr>
  <td><a href="#file_encryption">Using Encrypted Files</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;CIPHER=[AES|XTEA]<br />
    jdbc:h2:ssl://secureserv/~/testdb;CIPHER=AES<br />
    jdbc:h2:file:~/secure;CIPHER=XTEA<br />
  </td>
</tr>
<tr>
  <td><a href="#database_file_locking">File Locking Methods</a></td>
  <td>
    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 />
  </td>
</tr>
<tr>
  <td><a href="#database_only_if_exists">Only Open if it Already Exists</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;IFEXISTS=TRUE<br />
    jdbc:h2:file:~/sample;IFEXISTS=TRUE<br />
  </td>
</tr>
<tr>
    <td><a href="#do_not_close_on_exit">Don't Close the Database when the VM Exits</a></td>
    <td>
    jdbc:h2:&lt;url&gt;;DB_CLOSE_ON_EXIT=FALSE
    </td>
</tr>
<tr>
  <td><a href="#passwords">User Name and/or Password</a></td>
  <td>
    jdbc:h2:&lt;url&gt;[;USER=&lt;username&gt;][;PASSWORD=&lt;value&gt;]<br />
    jdbc:h2:file:~/sample;USER=sa;PASSWORD=123<br />
  </td>
</tr>
<tr>
  <td><a href="#log_index_changes">Log Index Changes</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;LOG=2<br />
    jdbc:h2:file:~/sample;LOG=2<br />
  </td>
</tr>
<tr>
  <td><a href="#trace_options">Debug Trace Settings</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;TRACE_LEVEL_FILE=&lt;level 0..3&gt;<br />
    jdbc:h2:file:~/sample;TRACE_LEVEL_FILE=3<br />
  </td>
</tr>
<tr>
  <td><a href="#ignore_unknown_settings">Ignore Unknown Settings</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;IGNORE_UNKNOWN_SETTINGS=TRUE<br />
  </td>
</tr>
<tr>
  <td><a href="#custom_access_mode">Custom File Access Mode</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;ACCESS_MODE_LOG=rws;ACCESS_MODE_DATA=rws<br />
  </td>
</tr>
<tr>
  <td><a href="#database_in_zip">Database in or Zip File</a></td>
  <td>
    jdbc:h2:zip:&lt;zipFileName&gt;!/&lt;databaseName&gt;<br />
    jdbc:h2:zip:~/db.zip!/test
  </td>
</tr>
<tr>
  <td><a href="#compatibility">Compatibility Mode</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;MODE=&lt;databaseType&gt;<br />
    jdbc:h2:~/test;MODE=MYSQL
  </td>
</tr>
<tr>
  <td><a href="#auto_reconnect">Auto-Reconnect</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;AUTO_RECONNECT=TRUE<br />
    jdbc:h2:tcp://localhost/~/test;AUTO_RECONNECT=TRUE
  </td>
</tr>
<tr>
  <td><a href="#auto_mixed_mode">Automatic Mixed Mode</a></td>
  <td>
    jdbc:h2:&lt;url&gt;;AUTO_SERVER=TRUE<br />
    jdbc:h2:~/test;AUTO_SERVER=TRUE
  </td>
</tr>
<tr>
  <td><a href="#other_settings">Changing Other Settings</a></td>
  <td>
    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 />
  </td>
</tr>
</table>

<br /><a name="embedded_databases"></a>
<h2>Connecting to an Embedded (Local) Database</h2>
<p>
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 recommended to use lowercase letters only.
The database name must be at least three characters long (a limitation of File.createTempFile).
To point to the user home directory, use ~/, as in: jdbc:h2:~/test.
</p>

<br /><a name="memory_only_databases"></a>
<h2>Memory-Only Databases</h2>
<p>
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.
</p><p>
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.
</p><p>
Sometimes 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>.
Accessing the same database in this way only works within the same virtual machine and
class loader environment.
</p><p>
It is also possible to access a memory-only database remotely
(or from multiple processes in the same machine) 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).
</p><p>
By default, when the last connection to a in-memory database is closed, the contents are lost.
This can be disabled by adding ;DB_CLOSE_DELAY=-1 to the database URL. That means to keep
the contents of an in-memory database as long as the virtual machine is alive, use
jdbc:h2:mem:test;DB_CLOSE_DELAY=-1
</p>

<br /><a name="file_encryption"></a>
<h2>Connecting to a Database with File Encryption</h2>
<p>
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:
</p>
<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>

<br /><a name="database_file_locking"></a>
<h2>Database File Locking</h2>
<p>
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.
</p><p>
The following file locking methods are implemented:
</p>
<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.
</li><li>The second method is 'socket' and opens a server socket. The socket method does
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.
</li><li>It is also possible to open the database without file locking;
in this case it is up to the application to protect the database files.
</li></ul>
<p>
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:
</p>
<pre>
String url = "jdbc:h2:~/test;FILE_LOCK=SOCKET";
</pre>
<p>
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:
</p>
<pre>
String url = "jdbc:h2:~/test;FILE_LOCK=NO";
</pre>
<p>
For more information about the algorithms please see in Advanced Topics under
File Locking Protocol.
</p>

<br /><a name="database_only_if_exists"></a>
<h2>Opening a Database Only if it Already Exists</h2>
<p>
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:
</p>
<pre>
String url = "jdbc:h2:/data/sample;IFEXISTS=TRUE";
</pre>

<br /><a name="closing_the_database"></a>
<h2>Closing the Database</h2>

<h3>Delayed Database Closing</h3>
<p>
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:
</p>
<pre>
SET DB_CLOSE_DELAY 10
</pre>
<p>
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>.
</p>

<br /><a name="do_not_close_on_exit"></a>
<h3>Don't Close the Database when the VM Exits</h3>
<p>
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).
For those cases, the automatic closing of the database can be disabled 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:
</p>
<pre>
String url = "jdbc:h2:~/test;DB_CLOSE_ON_EXIT=FALSE";
</pre>

<br /><a name="log_index_changes"></a>
<h2>Log Index Changes</h2>
<p>
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.
</p>

<br /><a name="ignore_unknown_settings"></a>
<h2>Ignore Unknown Settings</h2>
<p>
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.
</p>

<br /><a name="other_settings"></a>
<h2>Changing Other Settings when Opening a Connection</h2>
<p>
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.
</p>

<br /><a name="custom_access_mode"></a>
<h2>Custom File Access Mode</h2>
<p>
Usually, the database opens log, data and index files with the access mode 'rw', meaning
read-write (except for read only databases, where the mode 'r' is used).
To open a database in read-only mode if the files are not read-only, use
ACCESS_MODE_DATA=r.
Also supported are 'rws' and 'rwd'.
The access mode used for log files is set via ACCESS_MODE_LOG; for
data and index files use ACCESS_MODE_DATA.
These settings must be specified in the database URL:
</p>
<pre>
String url = "jdbc:h2:~/test;ACCESS_MODE_LOG=rws;ACCESS_MODE_DATA=rws";
</pre>
<p>
For more information see <a href="advanced.html#durability_problems">Durability Problems</a>.
On many operating systems the access mode 'rws' does not guarantee that the data is written to the disk.
</p>

<br /><a name="multiple_connections"></a>
<h2>Multiple Connections</h2>

<h3>Opening Multiple Databases at the Same Time</h3>
<p>
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.
</p>

<h3>Multiple Connections to the Same Database: Client/Server</h3>
<p>
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).
</p>

<h3>Multithreading Support</h3>
<p>
This database is multithreading-safe. That means, if an application is multi-threaded, it does not need
o 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 accessing the same database
at the same time, however if one thread executes a long running query, the other threads
need to wait.
</p>

<h3>Locking, Lock-Timeout, Deadlocks</h3>
<p>
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.
</p><p>
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:
</p>
<table><tr><th>Type of Lock</th><th>SQL Statement</th></tr>
<tr>
  <td>
    Read
  </td>
  <td>
    SELECT * FROM TEST<br />
    CALL SELECT MAX(ID) FROM TEST<br />
    SCRIPT
  </td>
</tr>
<tr>
  <td>
    Write
  </td>
  <td>
    SELECT * FROM TEST WHERE 1=0 FOR UPDATE
  </td>
</tr>
<tr>
  <td>
    Write
  </td>
  <td>
    INSERT INTO TEST VALUES(1, 'Hello')<br />
    INSERT INTO TEST SELECT * FROM TEST<br />
    UPDATE TEST SET NAME='Hi'<br />
    DELETE FROM TEST
  </td>
</tr>
<tr>
  <td>
    Write
  </td>
  <td>
    ALTER TABLE TEST ...<br />
    CREATE INDEX ... ON TEST ...<br />
    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.
</p>

<br /><a name="database_file_layout"></a>
<h2>Database File Layout</h2>
<p>
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:
</p>
<table><tr><th>File Name</th><th>Description</th><th>Number of Files</th></tr>
<tr><td>
    test.data.db
</td><td>
    Data file<br />
    Contains the data for all tables<br />
    Format: &lt;database&gt;.data.db
</td><td>
    1 per database
</td></tr>
<tr><td>
    test.index.db
</td><td>
    Index file<br />
    Contains the data for all (btree) indexes<br />
    Format: &lt;database&gt;.index.db
</td><td>
    1 per database
</td></tr>
<tr><td>
    test.0.log.db
</td><td>
    Log file<br />
    The log file is used for recovery<br />
    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>
    Database lock file<br />
    Exists only if the database is open<br />
    Format: &lt;database&gt;.lock.db
</td><td>
    1 per database
</td></tr>
<tr><td>
    test.trace.db
</td><td>
    Trace file<br />
    Contains trace information<br />
    Format: &lt;database&gt;.trace.db<br />
    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>
    Large object<br />
    Contains the data for BLOB or CLOB<br />
    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>
    Temporary file<br />
    Contains a temporary blob or a large result set<br />
    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>
    Hash index file<br />
    Contains the data for a linear hash index<br />
    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>
Database name and location are not stored inside the database names.
</p><p>
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).
</p><p>
As there is no platform specific data in the files, they can be moved to other operating systems
without problems.
</p>

<h3>Backup</h3>
<p>
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.
</p><p>
To backup data while the database is running, the SQL command SCRIPT can be used.
</p>

<br /><a name="logging_recovery"></a>
<h2>Logging and Recovery</h2>
<p>
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.
</p><p>
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.
</p><p>
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.
</p><p>
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.
</p>

<br /><a name="compatibility"></a>
<h2>Compatibility</h2>
<p>
All database engines behave a little bit different. Where possible, H2 supports the ANSI SQL standard,
and tries to be compatible to other databases. There are still a few differences however:
</p>
<p>
In MySQL text columns are case insensitive by default, while in H2 they are case sensitive. However
H2 supports case insensitive columns as well. To create the tables with case insensitive texts, append
IGNORECASE=TRUE to the database URL (example: jdbc:h2:~/test;IGNORECASE=TRUE).
</p>

<h3>Compatibility Modes</h3>
<p>
For certain features, this database can emulate the behavior of specific databases.
Not all features or differences of those databases are implemented.
Here is the list of currently supported modes and the difference to the regular mode:
</p>

<h3>DB2 Compatibility Mode</h3>
<p>
To use the IBM DB2 mode, use the database URL <code>jdbc:h2:~/test;MODE=DB2</code>
or the SQL statement <code>SET MODE DB2</code>.
</p>
<ul><li>For aliased columns, ResultSetMetaData.getColumnName() returns the alias name
    and getTableName() returns null.
</li><li>Support for the syntax [OFFSET .. ROW] [FETCH ... ONLY]
    as an alternative syntax for LIMIT .. OFFSET.
</li></ul>

<h3>Derby Compatibility Mode</h3>
<p>
To use the Apache Derby mode, use the database URL <code>jdbc:h2:~/test;MODE=Derby</code>
or the SQL statement <code>SET MODE Derby</code>.
</p>
<ul><li>For aliased columns, ResultSetMetaData.getColumnName() returns the alias name
    and getTableName() returns null.
</li><li>For unique indexes, NULL is distinct. That means only one row with NULL
    in one of the columns is allowed.
</li></ul>

<h3>HSQLDB Compatibility Mode</h3>
<p>
To use the HSQLDB mode, use the database URL <code>jdbc:h2:~/test;MODE=HSQLDB</code>
or the SQL statement <code>SET MODE HSQLDB</code>.
</p>
<ul><li>For aliased columns, ResultSetMetaData.getColumnName() returns the alias name
    and getTableName() returns null.
</li><li>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.
</li><li>Concatenation of a NULL with another value results in NULL. 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.
</li><li>For unique indexes, NULL is distinct. That means only one row with NULL
    in one of the columns is allowed.
</li></ul>

<h3>MS SQL Server Compatibility Mode</h3>
<p>
To use the MS SQL Server mode, use the database URL <code>jdbc:h2:~/test;MODE=MSSQLServer</code>
or the SQL statement <code>SET MODE MSSQLServer</code>.
</p>
<ul><li>For aliased columns, ResultSetMetaData.getColumnName() returns the alias name
    and getTableName() returns null.
</li><li>Identifiers may be quoted using square brackets as in [Test].
</li><li>For unique indexes, NULL is distinct. That means only one row with NULL
    in one of the columns is allowed.
</li></ul>

<h3>MySQL Compatibility Mode</h3>
<p>
To use the MySQL mode, use the database URL <code>jdbc:h2:~/test;MODE=MySQL</code>
or the SQL statement <code>SET MODE MySQL</code>.
</p>
<ul><li>When inserting data, if a column is defined to be NOT NULL and NULL is inserted,
    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.
</li><li>Creating indexes in the CREATE TABLE statement should be supported.
</li><li>The identifiers should be returned in lower case.
</li><li>When converting a floating point number to a integer, the fractional
    digits should not be truncated, but the value should be rounded.
</li></ul>

<h3>Oracle Compatibility Mode</h3>
<p>
To use the Oracle mode, use the database URL <code>jdbc:h2:~/test;MODE=Oracle</code>
or the SQL statement <code>SET MODE Oracle</code>.
</p>
<ul><li>For aliased columns, ResultSetMetaData.getColumnName() returns the alias name
    and getTableName() returns null.
</li><li>When using unique indexes, multiple rows with NULL in all columns
    are allowed, however it is not allowed to have multiple rows with the
    same values otherwise.
</li></ul>

<h3>PostgreSQL Compatibility Mode</h3>
<p>
To use the PostgreSQL mode, use the database URL <code>jdbc:h2:~/test;MODE=PostgreSQL</code>
or the SQL statement <code>SET MODE PostgreSQL</code>.
</p>
<ul><li>For aliased columns, ResultSetMetaData.getColumnName() returns the alias name
    and getTableName() returns null.
</li><li>Concatenation of a NULL with another value results in NULL. 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.
</li><li>When converting a floating point number to a integer, the fractional
    digits should not be truncated, but the value should be rounded.
</li><li>The system columns 'CTID' and 'OID' should be supported.
</li></ul>

<br /><a name="auto_reconnect"></a>
<h2>Auto-Reconnect</h2>
<p>
The auto-reconnect feature causes the JDBC driver to reconnect to
the database if the connection is lost. The automatic re-connect only
occurs when auto-commit is enabled; if auto-commit is disabled, an exception is thrown.
</p>
<p>
Re-connecting will open a new session. After an automatic re-connect,
variables and local temporary tables definitions (excluding data) are re-created.
The contents of the system table INFORMATION_SCHEMA.SESSION_STATE
contains all client side state that is re-created.
</p>

<br /><a name="auto_mixed_mode"></a>
<h2>Automatic Mixed Mode</h2>
<p>
Multiple processes can access the same database without having to explicitly
start the server. To do that, append <code>;AUTO_SERVER=TRUE</code> to the database URL.
In this case, the first connection to the database is made in embedded mode, and additionally a server is started.
If the database is already open in another process, the server mode is used.
</p>
<p>
When using this feature, auto-reconnect is enabled as well.
</p>
<p>
The application that opens the first connection to the database uses the embedded mode,
which is faster than the server mode. Therefore the main application should open
the database first if possible. A server is started on a random port.
This server allows remote connections, however only to this database.
In addition to the user name and password, the client sends the random key that is
stored in .lock.db file to the server.
</p>

<br /><a name="trace_options"></a>
<h2>Using the Trace Options</h2>
<p>
To find problems in an application, it is sometimes good to see what database operations
where executed. This database offers the following trace features:
</p>
<ul>
<li>Trace to System.out and/or a file
</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>

<h3>Trace Options</h3>
<p>
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).
The trace levels are 0 for OFF, 1 for ERROR (the default), 2 for INFO and 3 for DEBUG.
A database URL with both levels set to DEBUG is:
</p>
<pre>
jdbc:h2:~/test;TRACE_LEVEL_FILE=3;TRACE_LEVEL_SYSTEM_OUT=3
</pre>
<p>
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:
</p>
<pre>
SET TRACE_LEVEL_SYSTEM_OUT 3
</pre>

<h3>Setting the Maximum Size of the Trace File</h3>
<p>
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:
</p>
<pre>
SET TRACE_MAX_FILE_SIZE 1
</pre>

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

<h3>Enabling the Trace Option at Runtime by Manually Creating a File</h3>
<p>
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'.
This feature is disabled if the database is encrypted.
</p><p>
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.
</p>

<br /><a name="other_logging"></a>
<h2>Using Other Logging APIs</h2>
<p>
By default, this database uses its own native 'trace' facility. This facility is called 'trace' and not
'log' within this database to avoid confusion with the transaction log. Trace messages can be
written to both file and System.out. In most cases, this is sufficient, however sometimes
it is better to use the same facility as the application, for example Log4j. To do that, this
database support SLF4J.
</p>
<p>
<a href="http://www.slf4j.org">SLF4J</a> is a simple facade for various logging APIs
and allows to plug in the desired implementation at deployment time.
SLF4J supports implementations such as Logback, Log4j, Jakarta Commons Logging (JCL),
JDK 1.4 logging, x4juli, and Simple Log.
</p>
<p>
To enable SLF4J, set the file trace level to 4 in the database URL:
</p>
<pre>
jdbc:h2:~/test;TRACE_LEVEL_FILE=4
</pre>
<p>
Changing the log mechanism is not possible after the database is open, that means
executing the SQL statement SET TRACE_LEVEL_FILE 4 when the database is already open
will not have the desired effect. To use SLF4J, all required jar files need to be in the classpath.
If it does not work, check in the file &lt;database&gt;.trace.db for error messages.
</p>

<br /><a name="read_only"></a>
<h2>Read Only Databases</h2>
<p>
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 gets smaller. Do not delete the log file.
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().
</p>

<br /><a name="database_in_zip"></a>
<h2>Read Only Databases in Zip or Jar File</h2>
<p>
To create a read-only database in a zip, first create a regular persistent database, and then create a backup.
If you are using a database named 'test', an easy way to do that is using the Backup tool or the BACKUP SQL statement:
</p>
<pre>
BACKUP TO 'data.zip'
</pre>
<p>
The database must not have pending changes, that means you need to close all connections to the
database, open one single connection, and then execute the statement. Afterwards, you can log out,
and directly open the database in the zip file using the following database URL:
</p>
<pre>
jdbc:h2:zip:~/data.zip!/test
</pre>
<p>
Databases in a zip file are read-only. The performance for some queries will be slower than when using
a regular database, because random access in zip files is not supported (only streaming). How much this
affects the performance depends on the queries and the data. The database
is not read in memory; so large databases are supported as well. The same indexes are used than when using
a regular database.
</p>

<br /><a name="low_disk_space"></a>
<h2>Graceful Handling of Low Disk Space Situations</h2>
<p>
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.
</p><p>
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.
</p>

<h3>Opening a Corrupted Database</h3>
<p>
If a database cannot 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.
</p>

<br /><a name="computed_columns"></a>
<h2>Computed Columns / Function Based Index</h2>
<p>
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:
</p>
<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>
<p>
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:
</p>
<pre>
INSERT INTO ADDRESS(ID, NAME) VALUES(1, 'Miller');
SELECT * FROM ADDRESS WHERE UPPER_NAME='MILLER';
</pre>

<br /><a name="multi_dimensional"></a>
<h2>Multi-Dimensional Indexes</h2>
<p>
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.
</p><p>
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).
</p><p>
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.
</p>

<br /><a name="passwords"></a>
<h2>Using Passwords</h2>

<h3>Using Secure Passwords</h3>
<p>
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:
</p><p>
i'sE2rtPiUKtT (it's easy to remember this password if you know the trick)
</p>

<h3>Passwords: Using Char Arrays instead of Strings</h3>
<p>
Java Strings are immutable objects and cannot be safely 'destroyed' by the application.
After creating a String, it will remain in the main memory of the computer at least
until it is garbage collected. The garbage collection cannot be controlled by the application,
and even if it is garbage collected the data may still remain in memory.
It might also be possible that the part of memory containing the password
is swapped to disk (because not enough main memory is available).
</p><p>
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.
</p><p>
This database supports using char arrays instead of String to pass user and file passwords.
The following code can be used to do that:
</p>
<pre>
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>
<p>
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).
</p>

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

<br /><a name="user_defined_functions"></a>
<h2>User-Defined Functions and Stored Procedures</h2>
<p>
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:
</p>
<pre>
package org.h2.samples;
...
public class Function {
    public static boolean isPrime(int value) {
        return new BigInteger(String.valueOf(value)).isProbablePrime(100);
    }
}
</pre>
<p>
The Java function must be registered in the database by calling CREATE ALIAS:
</p>
<pre>
CREATE ALIAS IS_PRIME FOR "org.h2.samples.Function.isPrime"
</pre>
<p>
For a complete sample application, see src/test/org/h2/samples/Function.java.
</p>

<h3>Function Data Type Mapping</h3>
<p>
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'.
</p>

<h3>Functions that require a Connection</h3>
<p>
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.
</p>

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

<h3>Functions returning a Result Set</h3>
<p>
Functions may returns a result set. Such a function can be called with the CALL statement:
</p>
<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>
<p>
A function that returns a result set can create this result set from scratch using the SimpleResultSet tool:
</p>
<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>
<p>
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.
</p>
<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;
    }
    for(int x = 0; x &lt; id.intValue(); x++) {
        for(int y = 0; y &lt; id.intValue(); y++) {
            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>

<br /><a name="triggers"></a>
<h2>Triggers</h2>
<p>
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:
</p>
<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>
<p>
The connection can be used to query or update data in other tables.
The trigger then needs to be defined in the database:
</p>
<pre>
CREATE TRIGGER INV_INS AFTER INSERT ON INVOICE
  FOR EACH ROW CALL "org.h2.samples.TriggerSample"
</pre>
<p>
The trigger can be used to veto a change, by throwing a SQL Exception.
</p>

<br /><a name="compacting"></a>
<h2>Compacting a Database</h2>
<p>
Empty space in the database file is re-used automatically.
To re-build the indexes, the simplest 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:
</p>
<pre>
public static void compact(String dir, String dbName,
        String user, String password) throws Exception {
    String url = "jdbc:h2:" + dir + "/" + dbName;
    String file = "data/test.sql";
    Script.execute(url, user, password, file);
    DeleteDbFiles.execute(dir, dbName, true);
    RunScript.execute(url, user, password, file, null, false);
}
</pre>
<p>
See also the sample application org.h2.samples.Compact.
The commands SCRIPT / RUNSCRIPT can be used as well to create a backup
of a database and re-build the database from the script.
</p>

<br /><a name="cache_settings"></a>
<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=131072), or it can be changed at runtime using
SET CACHE_SIZE size.
</p><p>
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
queues are used. The 2Q algorithm is more resistant to table scans, however the overhead
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 cannot be changed
once the database is open.
</p><p>
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>

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