Copyright 2002-2005 Fred Toussi. Permission is granted to distribute this document without any alteration under the terms of the HSQLDB license. Additional permission is granted to the HSQLDB Development Group to distribute this document with or without alterations under the terms of the HSQLDB license.
$Date: 2007/03/24 11:39:08 $
Table of Contents
Many questions repeatedly asked in Forums and mailing lists are answered in this guide. If you want to use HSQLDB with your application, you should read this guide. This document covers system related issues. For issues related to SQL see the SQL Issues chapter.
The normal method of accessing an HSQLDB database is via the JDBC Connection interface. An introduction to different methods of providing database services and accessing them can be found in the SQL Issues chapter. Details and examples of how to connect via JDBC are provided in our JavaDoc for jdbcConnection.
Version 1.7.2 introduced a uniform method of distinguishing between different types of connection, alongside new capabilities to provide access to multiple databases. The common driver identifier is jdbc:hsqldb: followed by a protocol identifier (mem: file: res: hsql: http: hsqls: https:) then followed by host and port identifiers in the case of servers, then followed by database identifier.
Table 4.1. Hsqldb URL Components
Driver and Protocol | Host and Port | Database | ||||||||||
---|---|---|---|---|---|---|---|---|---|---|---|---|
| not available |
| ||||||||||
Lowercase, single-word identifier creates the in-memory database when the first connection is made. Subsequent use of the same Connection URL connects to the existing DB. The old form for the URL, jdbc:hsqldb:. creates or connects to the same database as the new form for the URL, jdbc:hsqldb:mem:. | ||||||||||||
| not available |
| ||||||||||
The file path specifies the database file. In the above examples the first one refers to a set of mydb.* files in the directory where the javacommand for running the application was issued. The second and third examples refer to absolute paths on the host machine. | ||||||||||||
| not available |
| ||||||||||
Database files can be loaded from one of the jars specified as part of the Java command the same way as resource files are accessed in Java programs. The /adirectory above stands for a directory in one of the jars. | ||||||||||||
|
|
| ||||||||||
The host and port specify the IP address or host name of the server and an optional port number. The database to connect to is specified by an alias. This alias is a lowercase string defined in the server.properties file to refer to an actual database on the file system of the server or a transient, in-memory database on the server. The following example lines in server.properties or webserver.properties define the database aliases listed above and accessible to clients to refer to different file and in-memory databases. database.0=file:/opt/db/accounts dbname.0=an_alias database.1=file:/opt/db/mydb dbname.1=enrollments database.2=mem:adatabase dbname.2=quickdb The old form for the server URL, e.g., jdbc:hsqldb:hsql//localhost connects to the same database as the new form for the URL, jdbc:hsqldb:hsql//localhost/ where the alias is a zero length string. In the example below, the database files lists.* in the /home/dbmaster/ directory are associated with the empty alias: database.3=/home/dbmaster/lists dbname.3= |
Each new JDBC Connection to a database can specify connection properties. The properties user and password are always required. In 1.8.0 the following optional properties can also be used.
Connection properties are specified either by establishing the connection via the:
DriverManager.getConnection (String url, Properties info);
method call, or the property can be appended to the full Connection URL.
Table 4.2. Connection Properties
get_column_name | true | column name in ResultSet |
This property is used for compatibility with other JDBC driver implementations. When true (the default), ResultSet.getColumnName(int c) returns the underlying column name When false, the above method returns the same value as ResultSet.getColumnLabel(int column) Example below: jdbc:hsqldb:hsql://localhost/enrollments;get_column_name=false When a ResultSet is used inside a user-defined stored procedure, the default, true, is always used for this property. | ||
ifexists | false | connect only if database already exists |
Has an effect only with mem: and file: database. When true, will not create a new database if one does not already exist for the URL. When false (the default), a new mem: or file: database will be created if it does not exist. Setting the property to true is useful when troubleshooting as no database is created if the URL is malformed. Example below: jdbc:hsqldb:file:enrollments;ifexists=true | ||
shutdown | false | shut down the database when the last connection is closed |
This mimics the behaviour of 1.7.1 and older versions. When the last connection to a database is closed, the database is automatically shut down. The property takes effect only when the first connection is made to the database. This means the connection that opens the database. It has no effect if used with subsequent, simultaneous connections. This command has two uses. One is for test suites, where connections to the database are made from one JVM context, immediately followed by another context. The other use is for applications where it is not easy to configure the environment to shutdown the database. Examples reported by users include web application servers, where the closing of the last connection conisides with the web app being shut down. |
In addition, when a connection to an in-process database creates a new database, or opens an existing database (i.e. it is the first connection made to the database by the application), all the user-defined database properties can be specified as URL properties. This can be used to specify properties to enforce more strict SQL adherence, or to change cache_scale or similar properties before the database files are created. However, for new databases, it is recommended to use the SET PROPERTY command for such settings.
HSQLDB relies on a set of properties files for different settings. Since 1.7.0 property naming has been streamlined and a number of new properties have been introduced.
In all properties files, values are case-sensitive. All values apart from names of files or pages are required in lowercase (e.g. server.silent=FALSE will have no effect, but server.silent=false will work).
The properties files and the settings stored in them are as follows:
Table 4.3. Hsqldb Server Properties Files
File Name | Location | Function |
---|---|---|
server.properties | the directory where the command to run the Server class is issued | settings for running HSQLDB as a database server communicating with the HSQL protocol |
webserver.properties | the directory where the command to run the WebServer class is issued | settings for running HSQLDB as a database server communicating with the HTTP protocol |
<dbname>.properties | the directory where all the files for a database are located | settings for each particular database |
Properties files for running the servers are not created automatically. You should create your own files that contain server.property=value pairs for each property.
The properties file for each database is generated by the database engine. This file can be edited after closing the database. In 1.8.0, most of these properties can be changed via SQL commands.
In both server.properties and webserver.properties files, supported values and their defaults are as follows:
Table 4.4. Property File Properties
Value | Default | Description |
---|---|---|
server.database.0 | test | the path and file name of the first database file to use |
server.dbname.0 | "" | lowercase server alias for the first database file |
server.urlid.0 | NONE | SqlTool urlid used by UNIX init script. (This property is not used if your are running Server/Webserver on a platform other than UNIX, or of you are not using our UNIX init script). |
server.silent | true | no extensive messages displayed on console |
server.trace | false | JDBC trace messages displayed on console |
In 1.8.0, each server can serve up to 10 different databases simultaneously. The server.database.0 property defines the filename / path whereas the server.dbname.0 defines the lowercase alias used by clients to connect to that database. The digit 0 is incremented for the second database and so on. Values for the server.database.{0-9} property can use the mem:, file: or res: prefixes and properties as discussed above under CONNECTIONS. For example,
database.0=mem:temp;sql.enforce_strict_size=true;
Values specific to server.properties are:
Table 4.5. Server Property File Properties
Value | Default | Description |
---|---|---|
server.port | 9001 (normal) or 554 (if TLS encrypted) | TCP/IP port used for talking to clients. All databases are served on the same port. |
server.no_system_exit | true | no System.exit() call when the database is closed |
Values specific to webserver.properties are:
Table 4.6. WebServer Property File Properties
Value | Default | Description |
---|---|---|
server.port | 80 | TCP/IP port used for talking to clients |
server.default_page | index.html | the default web page for server |
server.root | ./ | the location of served pages |
.<extension> | ? | multiple entries such as .html=text/html define the mime types of the static files served by the web server. See the source for WebServer.java for a list. |
All the above values can be specified on the command line to start the server by omitting the server. prefix.
If you want to start the server from within your application, as opposed to the command line or batch files, you should create an instance of Server or Web Server, then assign the properties in the form of a String and start the Server. An example of this can be found in the org.hsqldb.test.TestBase source.
Upgrading: If you have existing custom properties files, change the values to the new naming convention. Note the use of digits at the end of server.database.n and server.dbname.n properties.
Each database has its own <dbname>.properties file as part of a small group of files which also includes <dbname>.script and <dbname>.data. The properties files contain key/value pairs for some important settings.
In version 1.8.0 a new SQL command allows most database properties to be modified as follows:
SET PROPERTY "property_name" property_value
Properties that can be modified via SET PROPERTY are indicated in the table below. Other properties are indicated as PROPERTIES FILE ONLY and can be modified only by editing the .properties file after a shutdown and before a restart. Only the user-defined values listed below should ever be modified. Changing any other value could result in unexpected malfunction in database operations. Most of these values have been introduced for the new features since 1.7.0:
Table 4.7. Database-specific Property File Properties
Value | Default | Description |
---|---|---|
readonly | false | whole database is read-only |
When true, the database cannot be modified in use. This setting can be changed to true if the database is to be opened from a CD. Prior to changing this setting, the database should be closed with the SHUTDOWN COMPACT command to ensure consistency and compactness of the data. (PROPERTIES FILE ONLY) but can be used as a connection property to open a normal database as readonly. | ||
hsqldb.files_readonly | false | database files will not be written to |
When true, data in MEMORY tables can be modified and new MEMORY tables can be added. However, these changes are not saved when the database is shutdown. CACHED and TEXT tables are always readonly when this setting is true. (PROPERTIES FILE ONLY) | ||
hsqldb.cache_file_scale | 1 | Set larger data file limits. Once set, the limit will go up to 8GB. |
This property can be set to 8 to increase the size limit of the .data file from 2GB to 8GB. To apply the change to an existing database, SHUTDOWN SCRIPT should be performed first, then the property=value line below should be added to the .properties file before reopening the database. hsqldb.cache_file_scale=8 The property can be set with the SQL command (as opposed to changing the value in the properties file) when the database has no CACHED tables (e.g. a new database). (SET PROPERTY) | ||
sql.enforce_size | false | trimming and padding string columns |
This property is no longer supported. Use sql.enforce_sctrict_size | ||
sql.enforce_strict_size | false | size enforcement and padding string columns |
Conforms to SQL standards for size and precision of data types. When true, all CHARACTER, VARCHAR, NUMERIC and DECIMAL values that are in a row affected by an INSERT INTO or UPDATE statement are checked against the size specified in the SQL table definition. An exception is thrown if the value is too long. Also all CHARACTER values that are shorter than the specified size are padded with spaces. TIMESTAMP(0) and TIMESTAMP(6) are also allowed in order to specify the subsecond resolution of the values. When false (default), stores the exact string that is inserted. (SET PROPERTY) | ||
sql.tx_no_multi_rewrite | false | transaction management |
In the default READ_UNCOMMITED mode, a transaction can write over rows inserted or updated by another uncommitted transaction. Setting this property to true will raise an exception when such a write is attempted (SET PROPERTY) | ||
hsqldb.cache_scale | 14 | memory cache exponent |
Indicates the maximum number of rows of cached tables that are held in memory, calculated as 3 *(2**value) (three multiplied by (two to the power value)). The default results in up to 3*16384 rows from all cached tables being held in memory at any time. The value can range between 8-18. (SET PROPERTY). If the value is set via SET PROPERTY then it becomes effective after the next database SHUTDOWN or CHECKPOINT. (SET PROPERTY) | ||
hsqldb.cache_size_scale | 10 | memory cache exponent |
Indicates the average size of each row in the memory cache used with cached tables, calculated as 2**value (two to the power value). This result value is multiplied by the maximum number of rows defined by hsqldb.cache_scale to form the maximum number of bytes for all the rows in memory cache. The default results in 1024 bytes per row. This default, combined with the default number of rows, results in approximately 50MB of the .data file to be stored in the memory cache. The value can range between 6-20. (SET PROPERTY). If the value is set via SET PROPERTY then it becomes effective after the next database SHUTDOWN or CHECKPOINT. (SET PROPERTY) | ||
hsqldb.log_size | 200 | size of log when checkpoint is performed |
The value is the size in megabytes that the .log file can reach before an automatic checkpoint occurs. A checkpoint and rewrites the .script file and clears the .log file. The value can be changed via the SET LOGSIZE nnn SQL command. | ||
runtime.gc_interval | 0 | forced garbage collection |
This setting forces garbage collection each time a set number of result set row or cache row objects are created. The default, "0" means no garbage collection is forced by the program. This should not be set when the database engine is acting as a server inside an exclusive JVM. The setting can be useful when the database is used in-process with the application with some Java Runtime Environments (JRE's). Some JRE's increase the size of the memory heap before doing any automatic garbage collection. This setting would prevent any unnecessary enlargement of the heap. Typical values for this setting would probably be between 10,000 to 100,000. (PROPERTIES FILE ONLY) | ||
hsqldb.nio_data_file | true | use of nio access methods for the .data file |
When HSQLDB is compiled and run in Java 1.4 or higher, setting this property to false will avoid the use of nio access methods, resulting in somewhat reduced speed. If the data file is larger than 256MB when it is first opened, nio access methods are not used. Also, if the file gets larger than the amount of available computer memory that needs to be allocated for nio access, non-nio access methods are used. (SET PROPERTY). If used before defining any CACHED table, it applies to the current session, otherwise it comes to effect after a SHUTDOWN and restart or CHECKPOINT. | ||
hsqldb.default_table_type | memory | type of table created with unqualified CREATE TABLE |
The CREATE TABLE command results in a MEMORY table by default. Setting the value "cached" for this property will result in a cached table by default. The qualified forms such as CREATE MEMORY TABLE or CREATE CACHED TABLE are not affected at all by this property. (SET PROPERTY) | ||
hsqldb.applog | 0 | application logging level |
The default level 0 indicates no logging. Level 1 results in events related to persistence to be logged, including any failures. The events are logged in a file ending with .app.log | ||
textdb.* | 0 | default properties for new text tables |
Properties that override the database engine defaults for newly created text tables. Settings in the text table SET <tablename> SOURCE <source string> command override both the engine defaults and the database properties defaults. Individual textdb.* properties are listed in the Text Tables chapter. (SET PROPERTY) |
When connecting to an in-process database creates a new database, or opens an existing database (i.e. it is the first connection made to the database by the application), all the user-defined database properties listed in this section can be specified as URL properties.
Upgrading: From 1.7.0, the location of the database files can no longer be overridden by paths defined in the properties file. All files belonging to a database should reside in the same directory.
The property sql.compare_in_locale=true is no longer supported. If the line exists in a .properties file, it will switch the database to the collation for the current default. See the SET DATABASE COLLATION[2] command.
When HSQLDB is used in OpenOffice.org, some property values will have a different default. The properties and values are:
hsqldb.default_table_type=cached hsqldb.cache_scale=13 hsqldb.log_size=10; hsqldb.nio_data_file=false sql.enforce_strict_size=true
There are some database properties that are set with dedicated SQL commands beginning with SET.
Table 4.8. SQL command properties
SET WRITE_DELAY {{TRUE | FALSE} | <seconds> | <milliseconds> MILLIS |
The default is TRUE and indicates that the changes to the database that have been logged are synched to the file system once every 20 seconds. FALSE indicates there is no delay and at each commit a file synch operation is performed. Numeric values from 0 can also be specified for the synch delay. The purpose of this command is to control the amount of data loss in case of a total system crash. A delay of 1 second means at most the data written to disk during the last second before the crash is lost. All data written prior to this has been synced and should be recoverable This setting should be specified on the basis of the reliability of the hardware used for running the database engine, the type of disk system used, the possibility of power failure etc. Also the nature of the data stored should be considered. In general, when the system is very reliable, the setting can be left to the default. If it is not very reliable, or the data is critical a setting of 1 or 2 seconds would suffice. Only in the worst case scenario or with the most critical data should a setting of 0 or FALSE be specified as this will slow the engine down to the speed at which the file synch operation can be performed by the disk subsystem. Values down to 10 millisconds can be specified by adding MILLIS to the command, but in practice a delay of 100 milliseconds provides 99.99999% reliability with an average one system crash per 6 days. |
SET LOG_SIZE <numeric value> |
The engine writes out a log of all the changes to the database as they occur. This log is synched to the disk based on the WRITE_DELAY property above. The log is never reused unless there is an abnormal termination, i.e. the database process is terminated without SHUTDOWN, or it was terminated using SHUTDOWN IMMEDIATELY. The default maximum size of the .log file is 200 MB. When the maximum size is reached, a CHECKPOINT operation is performed. This operation will save the other database files in a consistent state and delete the old log. A value of 0 indicates no limit for the .log file. |
SET CHECKPOINT DEFRAG <numeric value> |
When rows in CACHED tables are updated or deleted, the spaces are mostly reused. However, in time, some unused spaces are left in the .data file, especially when large tables are dropped or their structure is modified. A CHECKPOINT operation does not normally reclaim the empty spaces, whereas CHECKPOINT DEFRAG always does. This property determines when a normal CHECKPOINT, whether initiated by an administrator or when the size of the log exceeds its limit. The numeric value is the number of megabytes of recorded empty spaces in the .data file that would force a DEFRAG operation. Low values result in more frequent DEFRAG operations. A value of 0 indicates no automatic DEFRAG is performed. The default is 200 megabytes of lost space. |
SET REFERENTIAL INTEGRITY {TRUE | FALSE} |
This is TRUE by default. If bulk data needs to be loaded into the database, this property can be set FALSE for the duration of bulk load operation. This allows loading data for related tables in any order. The property should be set TRUE after bulk load. If the loaded data is not guaranteed to conform to the referential integrity constraints, SQL queries should be run after loading to identify and modify any non-conforming rows. |