Chapter 11. System Management

Fred Toussi

The HSQL Development Group

$Revision: 5039 $

Copyright 2002-2012 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 HSQL Development Group to distribute this document with or without alterations under the terms of the HSQLDB license.

2012-08-06 00:10:58+0100

Table of Contents

Mode of Operation and Tables
Mode of Operation
Tables
Large Objects
Deployment context
Readonly Databases
ACID, Persistence and Reliability
Atomicity, Consistency, Isolation, Durability
Backing Up Database Catalogs
Making Online Backups
Making Offline Backups
Examining Backups
Restoring a Backup
Encrypted Databases
Creating and Accessing an Encrypted Database
Speed Considerations
Security Considerations
Monitoring Database Operations
External Statement Level Monitoring
Internal Statement Level Monitoring
Internal Event Monitoring
Log4J and JDK logging
Server Operation Monitoring
Database Security
Security Defaults
Authentication Control
Compatibility with Other RDBMS
PostgreSQL Compatibility
MySQL Compatibility
Firebird Compatibility
Apache Derby Compatibility
Oracle Compatibility
DB2 Compatibility
MS SQLServer and Sybase Compatibility
Statements
System Operations
Database Settings
SQL Conformance Settings
Cache, Persistence and Files Settings
Authentication Settings

Mode of Operation and Tables

HyperSQL has many modes of operation and features that allow it to be used in very different scenarios. Levels of memory usage, speed and accessibility by different applications are influenced by how HyperSQL is deployed.

Mode of Operation

The decision to run HyperSQL as a separate server process or as an in-process database should be based on the following:

  • When HyperSQL is run as a server on a separate machine, it is isolated from hardware failures and crashes on the hosts running the application.

  • When HyperSQL is run as a server on the same machine, it is isolated from application crashes and memory leaks.

  • Server connections are slower than in-process connections due to the overhead of streaming the data for each JDBC call.

  • You can reduce client/server traffic using SQL Stored procedures to reduce the number of JDBC execute calls.

  • During development, it is better to use a Server with server.silent=false, which displays the statements sent to the server on the console window.

  • To improve speed of execution for statements that are executed repeatedly, reuse a parameterized PreparedStatement for the lifetime of the connections.

Tables

TEXT tables are designed for special applications where the data has to be in an interchangeable format, such as CSV (comma separated values). TEXT tables should not be used for routine storage of data.

MEMORY tables and CACHED tables are generally used for data storage. The difference between the two is as follows:

  • The data for all MEMORY tables is read from the *.script file when the database is started and stored in memory. In contrast the data for cached tables is not read into memory until the table is accessed. Furthermore, only part of the data for each CACHED table is held in memory, allowing tables with more data than can be held in memory.

  • When the database is shutdown in the normal way, all the data for MEMORY tables is written out to the disk. In comparison, the data in CACHED tables that has changed is written out during operation and at shutdown.

  • The size and capacity of the data cache for all the CACHED tables is configurable. This makes it possible to allow all the data in CACHED tables to be cached in memory. In this case, speed of access is good, but slightly slower than MEMORY tables.

  • For normal applications it is recommended that MEMORY tables are used for small amounts of data, leaving CACHED tables for large data sets. For special applications in which speed is paramount and a large amount of free memory is available, MEMORY tables can be used for large tables as well.

  • You can change the type of the table with the SET TABLE <table name> TYPE { CACHED | MEMORY }statement.

Large Objects

HyperSQL 2.0 supports dedicated storage and access to BLOB and CLOB objects. These objects can have huge sizes. BLOB or CLOB is specified as the type of a column of the table. Afterwards, rows can be inserted into the table using a PreparedStatement for efficient transfer of large LOB data to the database. In mem: catalogs, CLOB and BLOB data is stored in memory. In file: catalogs, this data is stored in a single separate file which has the extension *.lobs. The size of this file can grow to huge, terabyte figures. By default, a minimum 32 KB is allocated to each LOB. You can reduced this if your LOBs are generally smaller.

LOB data should be store in the database using a JDBC PreparedStatement object. The streaming methods send the LOB to the database in one operation as a binary or character stream. Inside the database, the disk space is allocated as needed and the data is saved as it is being received. LOB data should be retrieved from the database using a JDBC ResultSet method. When a streaming method is used to retrieve a LOB, it is retrieved in large chunks in a transparent manner. LOB data can also be retrieved as String or byte[], but these methods use more memory and may not be practical for large objects.

LOB data is not duplicated in the database when a lob is copied from one table to another. The disk space is reused when a LOB is deleted and is no longer contained in any table. This happens only at the time of a CHECKPOINT.

By using a dedicated LOB store, HyperSQL achieves consistently high speeds (usually over 20MB / s) for both storage and retrieval of LOBs.

There is an internal LOBS schema in the database to store the id's, sizes and addresses of the LOBs (but not the actual LOBS) in a few system tables. This schema is stored in the database as MEMORY tables. Therefore the amount of JVM memory should be increased when more than tens of thousands of LOBs are stored in the database. If your database contains more than a few hundreds of thousands of LOBs and memory use becomes an issue, you can change one or all LOB schema tables to CACHED tables. See statements below:

Example 11.1. Using CACHED tables for the LOB schema

  SET TABLE SYSTEM_LOBS.BLOCKS TYPE CACHED
  SET TABLE SYSTEM_LOBS.LOBS TYPE CACHED
  SET TABLE SYSTEM_LOBS.LOB_IDS TYPE CACHED

Deployment context

The files used for storing HyperSQL database data are all in the same directory. New files are always created and deleted by the database engine. Two simple principles must be observed:

  • The Java process running HyperSQL must have full privileges on the directory where the files are stored. This include create and delete privileges.

  • The file system must have enough spare room both for the 'permanent' and 'temporary' files. The default maximum size of the *.log file is 50MB. The *.data file can grow to up to 16GB (more if the default has been increased). The .backup file can be up to the size of the *.data file. The *.lobs file can grow to several terabytes. The temporary files created at the time of a SHUTDOWN can be equal in size to the *.script file and the .data file.

Readonly Databases

A file: catalog can be made readonly permanently, or it can be opened as readonly. To make the database readonly, the property, value pair, readonly=true can be added to the .properties file of the database.

It is also possible to open a normal database as readonly. For this, the property can be included in the URL of the first connection to the database.

There is another option which allows MEMORY tables to be writeable, but without persisting the changes at SHUTDOWN. This option is activated with the property, value pair, files_readonly=true, which can be added to the .properties file of the database, or included in the URL of the first connection to the database. This option is useful for running application tests which operate on a predefined dataset.

ACID, Persistence and Reliability

HyperSQL 2.0 uses the same persistence mechanism as version 1.8, but with important enhancements. The code has proven reliable, as the last critical issue was fixed 2 years before the release of version 2.0.

There are further enhancements in version 2.2

  • More extensive locking mechanism has been added to code to support multithreaded access.

  • Incremental backup (an internal mechanism for crash protection) allows fast checkpoint and shutdown.

  • All files are synced at checkpoints and also just before closing.

  • The data file is enlarged in block increments

  • The NIO file access implementation has been improved

Persistence relies on the JVM, the operating system, and the computer hardware. A database system like HSQLDB can perform millions of read and write operations in an hour. As system hardware and software can go wrong, it is impossible to achieve zero failure rate. Therefore regular backups are recommended. HyperSQL 2.2 has built-in database backup and restore features, discussed elsewhere in this chapter.

A note regarding the NIO file access implementation: This implementation applies only to CACHED table data in the .data file. Other files are not accessed via NIO. There has been an issue with some JVM implementations of nio not releasing the file buffers after they were closed. HyperSQL uses a workaround which is recommended for Sun JVM's. This does not apply to other JVM's. In such environments, it is therefore recommended to test the CHECKPOINT DEFRAG operation and the shutting down and restarting the database inside the same Java process extensively with NIO. Use of NIO can be turned off if necessary.

Atomicity, Consistency, Isolation, Durability

Atomicity means a transaction either fails without changing the data, or succeeds. HyperSQL ensures atomicity both during operations and in the event of a system crash.

Consistency means all the implicit and explicit integrity constraints are always enforced. HyperSQL always enforces the constraints and at the same time does not allow unenforceable constraints (illegal forms of CHECK constraints) to be created.

Isolation means transactions do not interfere with each other. HyperSQL enforces isolation according to strict rules of the database isolation model (MVCC or LOCKS).

Durability means a committed transaction is protected in case of a system crash. HyperSQL ensures durability according to the setting for WRITE DELAY MILLIS. A zero delay setting results in an FileDescriptor#sync() call each time a transaction commits. A timed delay means the FileDescriptor#sync() call is executed in the given intervals and only the last transactions committed in the interval may be lost. The sync() call is also made at all critical points, including when a file is about to be closed. Durability of files requires a reliable JVM and disk storage system that stores the data safely with a sync() call. In practice, many systems are generally reliable in this respect.

Backing Up Database Catalogs

The database engine saves the files containing all the data in a file catalog when a shutdown takes place. It automatically recovers from an abnormal termination and preserves the data when the catalog is opened next time. In an ideal operating environment, where there is no OS crash, disk failure, bugs in code, etc. there would be no need regularly to backup a database. This is meant to say, the engine performs the routine shutdown procedure internally, therefore backing up catalogs is an insurance policy against all sorts of misadventure that are not under the control of the database engine.

The data for each catalog consists of up to 5 files in the same directory with the endings such as *.properties, *.script, etc., as detailed in previous chapters.

HyperSQL 2.2 includes commands to backup the database files into a single .tar or .tar.gz file archive. The backup can be performed by a command given in a JDBC session if the target database catalog is running, or on the command-line if the target catalog has been shutdown.

Making Online Backups

To back up a running catalog, obtain a JDBC connection and issue a BACKUP DATABASE command in SQL. In its most simple form, the command format below will backup the database as a single .tar.gz file to the given directory.

  BACKUP DATABASE TO <directory name> BLOCKING

The directory name must end with a slash to distinguish it as a directory, and the whole string must be in single quotes like so: 'subdir/nesteddir/'.

See the next section under Statements for details about the command and its options. See the sections below about restoring a backup.

Making Offline Backups

To back up an offline catalog, the catalog must be in shut down state. You will run a Java command like this. In this example, the database is named dbname and is in the dbdir directory. The backup is saved to a file named backup.tar in the tardir directory.

Example 11.2. Offline Backup Example

  java -cp hsqldb.jar org.hsqldb.lib.tar.DbBackup --save tardir/backup.tar dbdir/dbname


where tardir/backup.tar is a file path to the *.tar or *.tar.gz file to be created in your file system, and dbdir/dbname is the file path to the catalog file base name (in same fashion as in server.database.* settings and JDBC URLs with catalog type file:.

Examining Backups

You can list the contents of backup tar files with DbBackup on your operating system command line, or with any Pax-compliant tar or pax client (this includes GNU tar),

Example 11.3. Listing a Backup with DbBackup

  java -cp hsqldb.jar org.hsqldb.lib.tar.DbBackup --list tardir/backup.tar


You can also give regular expressions at the end of the command line if you are only interested in some of the file entries in the backup. Note that these are real regular expressions, not shell globbing patterns, so you would use .+script to match entries ending in "script", not *script.

You can examine the contents of the backup in their entirety by restoring the backup, as explained in the following section, to a temporary directory.

Restoring a Backup

You use DbBackup on your operating system command line to restore a catalog from a backup.

Example 11.4. Restoring a Backup with DbBackup

  java -cp hsqldb.jar org.hsqldb.lib.tar.DbBackup --extract tardir/backup.tar dbdir


where tardir/backup.tar is a file path to the *.tar or *.tar.gz file to be read, and dbdir is the target directory to extract the catalog files into. Note that dbdir specifies a directory path, without the catalog file base name. The files will be created with the names stored in the tar file (and which you can see as described in the preceding section).

Encrypted Databases

HyperSQL supports encrypted databases. Encryption services use the Java Cryptography Extensions (JCE) and uses the ciphers installed with the JRE. HyperSQL itself does not contain any cryptography code.

Three elements are involved in specifying the encryption method and key. A cipher, together with its configuration is identified by a string which includes the name of the cipher and optional parameters. A provider is the fully qualified class name of the cipher provider. A key is represented as a hexadecimal string.

Creating and Accessing an Encrypted Database

First, a key must be created for the desired cipher and configuration. This is done by calling the function CRYPT_KEY(<cipher spec>, <provider>). If the default provider (the built-in JVM ciphers) is used, then NULL should be specified as the provider. The CRYPT_KEY function returns a hexadecimal key. The function call can be made in any HyperSQL database, so long as the provider class is on the classpath. This key can be used to create a new encrypted database. Calls to this function always return different keys, based on a generated random values.

As an example, a call to CRYPT_KEY('Blowfish', null) returned the string, '604a6105889da65326bf35790a923932'. To create a new database, the URL below is used:

jdbc:hsqldb:file:<database path>;crypt_key=604a6105889da65326bf35790a923932;crypt_type=blowfish

The third property name is crypt_provider. This is specified only when the provider is not the default provider.

HyperSQL works with any symmetric cipher that may be available from the JVM.

The files that are encrypted include the .script, .data, .backup and .log files. The .lobs file is not encrypted by default. The property crypt_lobs=true must be specified to encrypt the .lobs file.

Speed Considerations

General operations on an encrypted database are performed the same as with any database. However, some operations are significantly slower than with the equivalent cleartext database. With MEMORY tables, there is no difference to the speed of SELECT statements, but data change statements are slower. With CACHED tables, the speed of all statements is slower.

Security Considerations

Security considerations for encrypted databases have been discussed at length in HSQLDB discussion groups. Development team members have commented that encryption is not a panacea for all security needs. The following issues should be taken into account:

  • Encrypted files are relatively safe in transport, but because databases contain many repeated values and words, especially known tokens such as CREATE, INSERT, etc., breaking the encryption of a database may be simpler than an unknown file.

  • Only the files are encrypted, not the memory image. Poking into computer memory, while the database is open, will expose the contents of the database.

  • HyperSQL is open source. Someone who has the key, can compile and use a modified version of the program that saves a full cleartext dump of an encrypted database

Therefore encryption is generally effective only when the users who have access to the crypt key are trusted.

Monitoring Database Operations

Database operations can be monitored at different levels using internal HyperSQL capabilities or add-ons.

External Statement Level Monitoring

Statement level monitoring allows you to gather statistics about executed statements. HyperSQL is supported by the monitoring tool JAMon (Java Application Monitor). JAMon is currently developed as the SourceForge project, jamonapi.

JAMon works at the JDBC level. It can monitor and gather statistics on different types of executed statements or other JDBC calls.

Early versions of JAMon were developed with HSQLDB and had to be integrated into HSQLDB at code level. The latest versions can be added on as a proxy in a much simpler fashion.

Internal Statement Level Monitoring

The internally-generated, individual sql log for the database can be enabled with the SET DATABASE EVENT LOG SQL LEVEL statement, described in this chapter. As all the executed statements are logged, there is an impact on speed. So you should only use this for debugging. Two levels of sql logging are supported.

Internal Event Monitoring

HyperSQL can log important internal events of the engine. These events occur during the operation of the engine, and are not always coupled with the exact type of statement being executed. Normal events such as opening and closing of files, or errors such as OutOfMemory conditions are examples of logged events.

HyperSQL supports two methods of logging. One method is specific to the individual database and is managed internally by HyperSQL. The other method is specific to JVM and is managed by a logging framework.

The internally-generated, individual log for the database can be enabled with the SET DATABASE EVENT LOG LEVEL statement, described in this chapter. This method of logging is very useful for desktop application deployment, as it provides an ongoing record of database operations.

Log4J and JDK logging

HyperSQL also supports log4J and JDK logging. The same event information that is passed to the internal log, is passed to external logging frameworks. These frameworks are typically configured outside HyperSQL. The log messages include the string "hsqldb.db." followed by the unique id (a 16 character string) of the database that generated the message, so they can be identified in a multi-database server context.

As the default JDK logging framework has several shortcomings, HyperSQL configures this logging framework for better operation. If you do not want HyperSQL to configure the JDK logging framework, you should include the system level property hsqldb.reconfig_logging=false in your environment.

Server Operation Monitoring

A Server or WebServer instance can be started with the property server.silent=false. This causes all the connections and their executed statements to be printed to stdout as the statements are submitted to the server.

Database Security

HyperSQL has extensive security features which are implemented at different levels and covered in different chapters of this guide.

  1. The server can use SSL and IP address access control lists. See the HyperSQL Network Listeners (Servers) chapter.

  2. You can define a system property to stop the database engine accessing the Java static functions that are on the classpath, apart from a limited set that you allow. See Securing Access to Classes in the SQL-Invoked Routines chapter.

  3. You can define a system property to allow access to files on the file system outside the database directory and its children. This access is only necessary if you use TEXT tables. See the Text Tables chapter.

  4. The database files can be encrypted. Discussed in this chapter.

  5. Within the database, the DBA privileges are required for system and maintenance jobs.

  6. You can define users and roles and grant them access on different database objects. Each user has a password and is granted a set of privileges. See the Access Control chapter.

  7. You can define a password complexity check function for new and changed passwords. This is covered below under Authentication Settings.

  8. You can use external authentication instead of internally stored password to authenticate users for each database. This is covered below under Authentication Settings.

HyperSQL security is multi-layered and avoids any loopholes to circumvent security. It is however the user's responsibility to enable the required level of security.

Security Defaults

The default setting are generally adequate for most embedded use of the database or for servers on the host that are accessed from the same machine. For servers accessed within a network, and especially for those accessed from outside the network, additional security settings must be used.

The default settings for server and web server do not use SSL or IP access control lists. These features are enabled programatically, or with the properties used to start the server.

The default settings allow a database user with the DBA role or with schema creation role to access static functions on the classpath. You can disable this feature or limit it to specific classes and methods. This can be done programatically or by setting a system property when you start a server.

If access to specific static functions is granted, then these functions must be considered as part of the database program and checked for any security flaws before inclusion in the classpath.

The default settings do not allow a user to access files outside the database directory. This access is for TEXT table source files. You can override this programatically or with a system property when you start a server.

The encryption of database file does not utilise any user-supplied information for encryption keys. This level of security is outside the realm of users and passwords.

The first user for a new database has the DBA role. This user name need was always SA in older versions of HSQLDB, but not in the latest versions. The name of the first DBA user and its password can be specified when the database is created by the first connection to the database. These settings are then stored in the database.

The initial user with the DBA role should be used for admin purposes only. At least one additional role should be created for normal database use in the application and at least one additional user should be created and granted this role. The new role should not be given the DBA role. It can be given the CREATE_SCHEMA role, which allows it to create and access multiple schemas. Alternatively, the user with the DBA role can create the schemas and their objects and then grant specific privileges on the objects to the non-DBA role.

Authentication Control

Authentication is the mechanism that determines if a user can access the database at all. Once authentication is performed, the authorization mechanism is used to determine which database objects the particular user can access. The default authentication mechanism is password authentication. Each user is created with a password, which is stored in the database and checked each time a new database connection is created.

Password Complexity Check

HyperSQL allows you to define a function that checks the quality of the passwords defined in the database. The passwords are stored in the database. Each time a user connects, the user's name and password are checked against the stored list of users and passwords. The connection attempt is rejected if there is no match.

External Authentication

You can use an external authentication mechanism instead of the internal authentication mechanism. HyperSQL allows you to define a function that checks the combination of database unique name, user name, and password for each connection attempt. The function can use external resources to authenticate the user. For example, a directory server may be used. The password may be ignored if the external resource can verify the user's credential without it.

You can override external authentication for a user with the ALTER USER statement. See the Access Control chapter

Compatibility with Other RDBMS

HyperSQL is used more than any other database engine for application testing and development targeted at other databases. Over the years, this usage resulted in developers finding and reporting many obscure bugs in HyperSQL, which have all been fixed in the latest version. Also, HyperSQL 2.0 has been written to the SQL Standard and avoids the traps caused by superficial imitation of existing RDBMS.

HyperSQL has many property settings that relax conformance to the Standard in order to allow compatibility with other RDBMS, without breaking the core integrity of the database. These properties are modified with SET DATABASE SQL statements described in the SQL Conformance Settings section of this chapter

The SQL Standard has existed since 1989 and has been expanded over the years in several revisions. Also, the X-Open specification has defined a number of SQL functions which are implemented by most RDBMS.

Each RDBMS supports additional functions that are not covered by the standard. Some RDBMS use non-standard syntax for some operations. Fortunately, most popular RDBMS products have introduced better compatibility with the Standard in their recent versions, but there are still some portability issues. HyperSQL overcomes the potability issues using these strategies

  • An extensive set of functions cover the SQL Standard, X-Open, and most of the useful functions that other RDBMS may support.

  • Database properties, which can be specified on the URL or as SQL statements, relax conformance to the Standard in order to allow non-standard comparisons and assignments allowed by other RDBMS.

  • Specific SQL syntax compatibility modes allow syntax and type names that are supported by some popular RDBMS.

  • User-defined types and functions, including aggregate functions, allow any type or function that is supported by some RDBMS to be defined and used.

In the future, the supported compatibility modes with other RDBMS will be expanded further.

PostgreSQL Compatibility

PostgreSQL is fairly compatible with the Standard, but uses some non-standard features.

  • Use <set database sql syntax PGS statement> to enable the PostgreSQL's non-standard features. References to SERIAL, BIGSERIAL and TEXT data types, as well as sequence functions, are translated into HSQLDB equivalents.

  • Use MVCC if your application is multi-user

  • PostgreSQL functions are generally supported

  • For identity columns, PostgreSQL uses a non-standard linkage with an external identity sequence. In most cases, this can be converted to GENERATED BY DEFAULT AS IDENTITY. In those cases where the identity sequence needs to be shared by multiple tables, you can use a new HyperSQL 2.2 feature GENERATED BY DEFAULT AS SEQUENCE <sequence name>, which is the equivalent of the PostgreSQL implementation.

  • In CREATE TABLE statements, the SERIAL and BIGSERIAL types are translated into INTEGER or BIGINT, with GENERATED BY DEFAULT AS IDENTITY. Usage of DEFAULT NEXTVAL(<sequence name>) is supported so long as the <sequence name> refers to an existing sequence. This usage is translated into GENERATED BY DEFAULT AS SEQUENCE <sequence name>.

  • In SELECT and other statements, the NEXTVAL(<sequence name>) and LASTVAL() functions are supported and translated into HyperSQL's NEXT VALUE FOR <sequence name> and IDENTITY() expressions.

  • PostgreSQL uses a non-standard expression, SELECT 'A Test String' to return a single row table. The standard form is VALUES('A Test String'). In PGS syntax mode, this type of SELECT is supported.

  • HyperSQL supports SQL Standard ARRAY types. PostgreSQL also supports this, but not entirely according to the Standard.

  • SQL routines are portable, but some syntax elements are different and require changes.

  • You may need to use SET DATABASE SQL TDC { DELETE | UPDATE } FALSE statements, as PostgreSQL does not enforce the subtle rules of the Standard for foreign key cascading deletes and updates.

MySQL Compatibility

MySQL had many incompatibilities with the Standard. The latest versions have introduced much greater compatibly, but some of these features have to be turned on via properties. You should therefore check the current Standard compatibility settings of your MySQL database and use the available HyperSQL properties to achieve closer results. If you avoid the few anti-Standard features of MySQL you can port your databases to HyperSQL.

HyperSQL does not have the following non-standard limitations of MySQL.

  • Win HyperSQL, an UPDATE statement can update UNIQUE and PRIMARY KEY columns of a table without causing an exception due to temporary violation of constraints. These constraints are checked at the end of execution, therefore there is no need for an ORDER BY clause in an UPDATE statement.

  • MySQL foreign key constraints are not enforced by the default MyISAM engine. Be aware of the possibility of data being rejected by HyperSQL due to these constraints.

  • With HyperSQL INSERT or UPDATE statements either succeed or fail due to constraint violation. MySQL has the non-standard IGNORE overrides to ignore violations, which is not accepted by HyperSQL.

  • Unlike MySQL, HyperSQL allows you to modify a table with an INSERT, UPDATE or DELETE statement which selects from the same table in a subquery.

Follow the guidelines below for converting MySQL databases and applications.

  • Use <set database sql syntax MYS statement> to enable support for AUTO_INCREMENT and TEXT data types. These type definitions are translated into HSQLDB equivalents.

  • Use MVCC with <set database transaction control statement> if your application is multi-user.

  • Avoid storing invalid values, for example invalid dates such as '0000-00-00' or '2001-00-00' which are rejected by HyperSQL.

  • Avoid the MySQL feature that trims spaces at the end of CHAR values.

  • In MySQL, a database is the same as a schema. In HyperSQL several schemas can exist in the same database and accessed transparently. In addition a HyperSQL server supports multiple separate databases.

  • In MySQL, older, non-standard, forms of database object name case-sensitivity make is difficult to port applications. Use the latest form which encloses case-sensitive names in double quotes.

  • MySQL functions are generally supported, including GROUP_CONCAT.

  • For fine control over type conversion, check the settings for <set database sql convert truncate statement>

  • If you use concatenation of possibly NULL values in your select statements, you may need to change the setting with the <set database sql concat nulls statement>

  • MySQL supports most SQL Standard types (except INTERVAL types), as well as non-standard types, which are also supported by HyperSQL. Supported types include SMALLINT, INT, BIGINT, DOUBLE, FLOAT, DECIMAL, NUMERIC, VARCHAR, CHAR, BINARY, VARBINARY, BLOB, DATE, TIMESTAMP (all Standard SQL) and TINYINT, DATETIME (non Standard).

  • MySQL uses a non-standard expression, SELECT 'A Test String' to return a single row table. The standard form is VALUES('A Test String'). In MYS syntax mode, this type of SELECT is supported.

  • SQL user-defined function and procedure syntax is very similar to SQL Standard syntax. A few changes may still be required.

Firebird Compatibility

Firebird generally follows the SQL Standard. Applications can be ported to HyperSQL without difficulty.

Apache Derby Compatibility

Apache Derby supports a smaller subset of the SQL Standard compared to HyperSQL. Applications can be ported to HyperSQL without difficulty.

  • Use MVCC with <set database transaction control statement> if your application is multi-user.

  • HyperSQL supports Java language functions and stored procedures with the standard syntax, which is similar to the way Derby supports these features.

Oracle Compatibility

Recent versions of Oracle support Standard SQL syntax for outer joins and many other operations. In addition, HyperSQL features a setting to support Oracle syntax and semantics for the most widely used non-standard features.

  • Use <set database sql syntax ORA statement> to enable support for some non-standard syntax of Oracle.

  • Use MVCC with <set database transaction control statement> if your application is multi-user.

  • Fine control over MVCC deadlock avoidance is provided by the <set database transaction rollback on conflict statement> and the corresponding hsqldb.tx_conflict_rollback connection property.

  • If your application relies on Oracle behaviour for nulls in multi-column UNIQUE constraints, use <set database sql unique nulls statement> to change the default.

  • If you use the non-standard concatenation of possibly NULL values in your select statements, you may need to change the setting for <set database sql concat nulls statement>.

  • Many Oracle functions are supported, including no-arg functions such as SYSDATE and SYSTIMESTAMP and more complex ones such as TO_DATE and TO_CHAR.

  • Non-standard data type definitions such as NUMBER, VARCHAR2, NVARCHAR2, BINARY_DOUBLE, BINARY_FLOAT, LONG, RAW are translated into the closest HyperSQL / SQL Standard equivalent in ORA mode.

  • The DATE type is interpreted as TIMESTAMP(0) in ORA syntax mode.

  • The DUAL table and the expressions, ROWNUM, CURRVAL, NEXTVAL are supported in ORA syntax mode.

  • HyperSQL natively supports operations involving datetime and interval values. These features are based on the SQL Standard.

  • Many subtle automatic type conversions, syntax refinements and other common features are supported.

  • SQL routines are generally portable, but some changes may be required.

DB2 Compatibility

DB2 is highly compatible with the SQL Standard (except its lack of support for the INFORMATION_SCHEMA). Applications can be ported to HyperSQL without difficulty.

  • Use <set database sql syntax DB2 statement> to enable support for some non-standard syntax of DB2.

  • Use MVCC with <set database transaction control statement> if your application is multi-user.

  • HyperSQL supports almost the entire syntax of DB2 together with many of the functions. Even local temporary tables using the SESSION pseudo schema are supported.

  • The DB2 binary type definition FOR BIT DATA, as well as empty definition of column default values are supported in DB2 syntax mode.

  • Many DB2 functions are supported.

  • The DUAL table and the expressions, ROWNUM, CURRVAL, NEXTVAL are supported in DB2 syntax mode.

  • SQL routines are highly portable with minimal change.

MS SQLServer and Sybase Compatibility

SQLServer has some incompatibilities with the Standard syntax. The most significant is the use of square brackets instead of double quotes for case-sensitive column names.

  • Use <set database sql syntax MSS statement> to enable support for the CONVERT(<type definition>, <expression) function with switched order of arguments

  • Use MVCC with <set database transaction control statement> if your application is multi-user.

  • If you use the non-standard concatenation of possibly NULL values in your select statements, you may need to change the setting for <set database sql concat nulls statement>.

  • HyperSQL supports + for string concatenation. It also supports many functions supported by these dialects.

  • SQLServer uses a non-standard expression, SELECT 'A Test String' to return a single row table. The standard form is VALUES('A Test String'). In MSS syntax mode, this type of SELECT is supported.

  • SQL routines need quite a lot of changes.

Statements

System level statements are listed in this section. Statements that begin with SET DATABASE or SET FILES are for properties that have an effect on the normal operation of HyperSQL. The effects of these statements are also discussed in different chapters.

System Operations

These statements perform a system level action.

SHUTDOWN

shutdown statement

<shutdown statement> ::= SHUTDOWN [IMMEDIATELY | COMPACT | SCRIPT]

Shutdown the database. If the optional qualifier is not used, a normal SHUTDOWN is performed. A normal SHUTDOWN ensures all data is saved correctly and the database opens without delay on next use.

SHUTDOWN

Normal shutdown saves all the database files, then deletes the .log file (and the .backup file in the default mode). This does the same thing as CHECKPOINT, but closes the database when it completes. The database opens without delay on next used.

SHUTDOWN IMMEDIATELY

Saves the *.log file and closes the database files. This is the quickest form of shutdown. This command should not be used as the routine method of closing the database, because when the database is accessed next time, it may take a long time to start.

SHUTDOWN COMPACT

This is similar to normal SHUTDOWN, but reduces the *.data file to its minimum size. It can take much longer than normal SHUTDOWN. This shouldn't be used as routine.

SHUTDOWN SCRIPT

This is similar to SHUTDOWN COMPACT, but it does not rewrite the *.data and text table files. After SHUTDOWN SCRIPT, only the *.script and *.properties files remain. At the next startup, these files are processed and the *.data file is created if there are cached tables. This command in effect performs part of the job of SHUTDOWN COMPACT, leaving the other part to be performed automatically at the next startup.

This command produces a full script of the database which can be edited for special purposes prior to the next startup.

Only a user with the DBA role can execute this statement.

BACKUP DATABASE

backup database statement

<backup database statement> ::= BACKUP DATABASE TO <file path> [SCRIPT] {[NOT] COMPRESSED} {[NOT] BLOCKING}

Backup the database to specified <file path> for archiving purposes.

The <file path> can be in two forms. If the <file path> ends with a forward slash, it specifies a directory. In this case, an automatic name for the archive is generated that includes the date, time and the base name of the database. The database is backed up to this archive file in the specified directory. The archive is in .tar.gz or .tar format depending on whether it is compressed or not.

If the <file path> does not end with a forward slash, it specifies a user-defined file name for the backup archive. The file extension must be either .tar.gz or .tar and this must match the compression option.

The default set of options is COMPRESSED BLOCKING.

If SCRIPT is specified, the backup will contain a *.script file, which contain all the data and settings of the database. Otherwise, it consists of the current snapshot of all database files.

If NOT COMPRESSED is specified, the backup is a tar file, without compression. Otherwise, it is in gzip format.

The qualifier, BLOCKING, means all database operations are suspended during backup. During backup, a CHECKPOINT command is silently executed. This mode is always used when SCRIPT is specified.

Hot backup is performed if NOT BLOCKING is specified. In this mode, the database can be used during backup. This mode should only be used with very large databases. A hot backup set is less compact and takes longer to restore and use than a normal backup set produced with the BLOCKING option. You can perform a CHECKPOINT just before a hot backup in order to reduce the size of the backup set.

The HyperSQL jar also contains a program that creates an archive of an offline database. It also contains a program to expand an archive into database files. These programs are documented in this chapter under Backing up Database Catalogs.

Only a user with the DBA role can execute this statement.

CHECKPOINT

checkpoint statement

<checkpoint statement> ::= CHECKPOINT [DEFRAG]

Closes the database files, rewrites the script file, deletes the log file and opens the database. If DEFRAG is specified, also shrinks the *.data file to its minimum size.

Only a user with the DBA role can execute this statement.

Only a user with the DBA role can execute this statement.

SCRIPT

script statement

<script statement> ::= SCRIPT [<file name>]

Returns a script containing SQL statements that define the database, its users, and its schema objects. If <file name> is not specified, the statements are returned in a ResultSet, with each row containing an SQL statement. No data statements are included in this form. The optional file name is a single-quoted string. If <file name> is specified, then the script is written to the named file. In this case, all the data in all tables of the database is included in the script as INSERT statements.

Only a user with the DBA role can execute this statement.

Database Settings

These statements change the database settings.

SET DATABASE COLLATION

set database collation statement

<set database collation statement> ::= SET DATABASE COLLATION <collation name> [ NO PAD | PAD SPACE ]

Each database can have its own default collation. Sets the collation from the set of collations supported by HyperSQL. Once this command has been issued, the database can be opened in any JVM and will retain its collation.

All collations pad the shorter string with spaces when two strings are compared. If NO PAD is specified, comparison is performed without padding. The default system collation is named SQL_TEXT. To use the default without padding use SET DATABASE COLLATION SQL_TEXT NO PAD.

Only a user with the DBA role can execute this statement.

SET DATABASE DEFAULT RESULT MEMORY ROWS

set database default result memory rows statement

<set database default result memory rows> ::= SET DATABASE DEFAULT RESULT MEMORY ROWS <unsigned integer literal>

Sets the maximum number of rows of each result set and internal temporary table that is held in memory. Temporary tables includes views, schema-based and session-based TEMPORARY tables, transient tables for subqueries, and INFORMATION_SCHEMA tables.

This setting applies to all sessions. Individual sessions can change the value with the SET SESSION RESULT MEMORY ROWS statement. The default is 0, meaning all result sets are held in memory.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.result_max_memory_rows.

SET DATABASE DEFAULT TABLE TYPE

set database default table type statement

<set database default table type> ::= SET DATABASE DEFAULT TABLE TYPE { CACHED | MEMORY }

Sets the type of table created when the next CREATE TABLE statement is executed. The default is MEMORY.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.default_table_type.

SET DATABASE EVENT LOG LEVEL

set database event log level statement

<set database event log level> ::= SET DATABASE EVENT LOG [ SQL ] LEVEL { 0 | 1 | 2 | 3 }

When the SQL option is not used, this statement sets the amount of information logged in the internal, database-specific event log. Level 0 means no log. Level 1 means only important (error) events. Level 2 means more events, including both important and less important (normal) events. Level 3 includes even more details. For readonly and mem: databases, if the level is set above 0, the log messages are directed to stderr.

The events are logged in a file with the extension .app.log alongside the main database files.

This is equivalent to the connection property hsqldb.applog.

When the SQL option is used, this statement logs the SQL statements as they are executed. Each log line contains the timestamp and the session number, followed by the SQL statement and JDBC arguments if any.

Levels 1 and 2 are supported. Level 1 only logs commits and rollbacks, while Level 2 logs all statements.

The logged lines are stored in a file with the extension .sql.log alongside the main database files.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.sqllog.

SET DATABASE GC

set database gc statement

<set database gc statement> ::= SET DATABASE GC <unsigned integer literal>

An optional property which forces calls to System.gc() after the specified number of row operations. The default value for this property is 0, which means no System.gc() calls. Usual values for this property range from 10000 depending on the system and the memory allocation. This property may be useful in some in-process deployments, especially with older JVM implementations.

Only a user with the DBA role can execute this statement.

SET DATABASE UNIQUE NAME

set database unique name

<set database unique name statement> ::= SET DATABASE UNIQUE NAME <identifier>

Each HyperSQL catalog (database) has an engine-generated internal name. This name is a 16 character long string, beginning with HSQLDB and based on the time of creation of the database. The name is used for the log events that are sent to external logging frameworks. The new name must be exactly 16 characters long with no spaces.

Only a user with the DBA role can execute this statement.

SET DATABASE TRANSACTION CONTROL

set database transaction control statement

<set database transaction control statement> ::= SET DATABASE TRANSACTION CONTROL { LOCKS | MVLOCKS | MVCC }

Set the concurrency control system for the database. It can be issued only when all sessions have been committed or rolled back. This command and its modes is discussed in the Sessions and Transactions chapter.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.tx.

SET DATABASE TRANSACTION ROLLBACK ON CONFLICT

set database transaction rollback on conflict statement

<set database transaction rollback on conflict statement> ::= SET DATABASE TRANSACTION ROLLBACK ON CONFLICT { TRUE | FALSE }

When a transaction deadlock or conflict is about to happen, the current transaction is rolled back and an exception is raised. When this property is set false, the transaction is not rolled back. Only the latest statement that would cause the conflict is undone and an exception is raised. The property should not be changed unless the application can quickly perform an alternative statement and complete the transaction. It is provided for compatibility with other database engines which do not roll back the transaction upon deadlock. This command is also discussed in the Sessions and Transactions chapter.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.tx_conflict_rollback.

SET DATABASE DEFAULT ISOLATION LEVEL

set database default isolation level statement

<set database default isolation level> ::= SET DATABASE DEFAULT ISOLATION LEVEL { READ COMMITTED | SERIALIZABLE }

Sets the transaction isolation level for new sessions. The default is READ COMMITTED. Each session can also set its isolation level.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.tx_level.

SET DATABASE TEXT TABLE DEFAULTS

set database text table defaults statement

<set database text table defaults statement> ::= SET DATABASE TEXT TABLE DEFAULTS <character literal>

An optional property to override default text table settings. The string literal has the same format as the string used for setting the data source of a text table, but without the file name. See the Text Tables chapter.

Only a user with the DBA role can execute this statement.

SQL Conformance Settings

These statements modify the level of conformance to the SQL Standard in different areas. The settings that specify SQL SYNTAX are for compatibility with other database engines and are FALSE by default. For all the rest of the settings, TRUE means better conformance to the Standard (unless the Standard defines the behaviour as implementation dependent). The default value of a few of these settings is FALSE, due to widespread non-conforming statements that are already in use in user applications or statements generated by object relational tools. So long as it is practical, it is best to set the non-conforming defaults to TRUE in order to improve the quality of the database application.

SET DATABASE SQL SIZE

set database sql size statement

<set database sql size statement> ::= SET DATABASE SQL SIZE { TRUE | FALSE }

Enable or disable enforcement of column sizes for CHAR and VARCHAR columns. The default is TRUE, meaning table definition must contain VARCHAR(n) instead of VARCHAR.

SQL Standard requires enforcement.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.enforce_size.

SET DATABASE SQL NAMES

set database sql names statement

<set database sql names statement> ::= SET DATABASE SQL NAMES { TRUE | FALSE }

Enable or disable full enforcement of the rule that prevents SQL keywords being used for database object names such as columns and tables. The default is FALSE, meaning disabled.

SQL Standard requires enforcement. It is better to enable this check, in order to improve the quality and correctness of SQL statements.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.enforce_names.

SET DATABASE SQL REGULAR NAMES

set database sql regular names statement

<set database sql regular names statement> ::= SET DATABASE SQL REGULAR NAMES { TRUE | FALSE }

Enable or disable use of the underscore character at the beginning, or the dollar character anywhere in database object names such as columns and tables. The default is TRUE, meaning disabled.

SQL Standard does not allow the underscore character at the start of names, and does not allow the dollar character anywhere in a name. This setting can be changed for compatibility with existing database or for porting databases which include names that do not conform to the Standard.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.regular_names.

SET DATABASE SQL REFERENCES

set database sql references statement

<set database sql references statement> ::= SET DATABASE SQL REFERENCES { TRUE | FALSE }

This command can enable or disable full enforcement of the rule that prevents ambiguous column references in SQL statements (usually SELECT statements). A column reference is ambiguous when it is not qualified by a table name or table alias and can refer to more than one column in a JOIN list.

The property is FALSE by default.

SQL Standard requires enforcement. It is better to enable this check, in order to improve the quality and correctness of SQL statements. When false, the first matching table is used to resolve the column reference.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.enforce_refs.

SET DATABASE SQL TYPES

set database sql types statement

<set database sql types statement> ::= SET DATABASE SQL TYPES { TRUE | FALSE }

This command can enable or disable full enforcement of the rules that prevents illegal type conversions and parameters or nulls without type in SQL statements (usually SELECT statements). For example an INTEGER column or a DATE column cannot be compared to a character string or searched with a LIKE expression when the property is TRUE.

The property is FALSE by default.

SQL Standard requires enforcement. It is better to enable this check, in order to improve the quality and correctness of SQL statements.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.enforce_type.

SET DATABASE SQL TDC DELETE

set database sql tdc delete statement

<set database sql tdc delete statement> ::= SET DATABASE SQL TDC DELETE { TRUE | FALSE }

This command can enable or disable full enforcement of the SQL Standard rules that prevents triggered data change exceptions caused by ON DELETE CASCADE clauses of foreign key constraint.

When there are multiple constraints, a row may be updated by one constraint and deleted by another constraint in the same operation. This is not allowed by default. Changing this to false allows such violations of the Standard to pass without an exception.

The property is TRUE by default.

SQL Standard requires enforcement, therefore this property shouldn't be changed unless an application written for a non-conforming RDBMS needs it.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.enforce_tdc_delete.

SET DATABASE SQL TDC UPDATE

set database sql tdc update statement

<set database sql tdc update statement> ::= SET DATABASE SQL TDC UPDATE { TRUE | FALSE }

This command can enable or disable full enforcement of the SQL Standard rules that prevents triggered data change exceptions caused by multiple ON UPDATE or ON DELETE SET clauses of foreign key constraint. When there are multiple constraints, a field in a row may be updated by two constraints to different values in the same operation. This is not allowed by default. Changing this to FALSE allows such violations of the Standard to pass without an exception.

The property is TRUE by default.

SQL Standard requires enforcement, therefore this property shouldn't be changed unless an application written for a non-conforming RDBMS needs it.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.enforce_tdc_update.

SET DATABASE SQL TRANSLATE TTI TYPES

set database sql translate tti types statement

<set database sql translate tti types statement> ::= SET DATABASE SQL TRANSLATE TTI TYPES { TRUE | FALSE }

The JDBC Specification up to version 4.1 does not support some SQL Standard built-in types, therefore these types must be translated to a supported type when accessed through JDBC ResultSet and PreparedStatement methods.

If the property is true, the TIME / TIMESTAMP WITH TIME ZONE types and INTERVAL types are represented in JDBC methods of ResultSetMetaData and DatabaseMetaData as JDBC datetime types without time zone and the VARCHAR type respectively. The original type names are preserved.

The property is TRUE by default. If set to FALSE, the type codes for WITH TIME ZONE types will be SQL type codes as opposed to JDBC type codes.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property jdbc.translate_tti_types.

SET DATABASE SQL CONCAT NULLS

set database sql concat nulls statement

<set database sql concat nulls statement> ::= SET DATABASE SQL CONCAT NULLS { TRUE | FALSE }

When the property is TRUE, concatenation of a null value with a not-null value results in a null value. When the property is FALSE this type of concatenation result in the not-null value.

Setting this property FALSE results in concatenation behaviour similar to Oracle or MS SQL Server.

SQL Standard requires a NULL result..

The property is TRUE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.concat_nulls.

SET DATABASE SQL UNIQUE NULLS

set database sql unique nulls statement

<set database sql unique nulls statement> ::= SET DATABASE SQL UNIQUE NULLS { TRUE | FALSE }

When the property is TRUE, with multi-column UNIQUE constraints, it is possible to insert multiple rows for which one or more of the values for the constraint columns is NULL. When the property is FALSE, if there is any not-null value in the columns, then the set of values is compared to the existing rows and if there is a match, an exception is thrown. The setting FALSE, makes the behaviour more restrictive. For example, inserting (1, null) twice is possible by default, but not possible when the property is FALSE.

Setting this property FALSE results in UNIQUE constraint behaviour similar to Oracle.

SQL Standard requires the default (TRUE) behaviour.

The property is TRUE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.unique_nulls.

SET DATABASE SQL CONVERT TRUNCATE

set database sql unique convert truncate

<set database sql convert truncate statement> ::= SET DATABASE SQL CONVERT TRUNCATE { TRUE | FALSE }

When the property is TRUE, conversion from a floating point value (a DOUBLE value) to an integral type always truncates the fractional part. When the property is FALSE, rounding takes place instead of truncation. For example, assigning the value 123456E-2 to an integer column will result in 1234 by default, but 1235 when the property is FALSE.

Standard SQL considers this behaviour implementation dependent.

The property is TRUE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.convert_trunc.

SET DATABASE SQL AVG SCALE

set database sql avg scale

<set database sql avg scale> ::= SET DATABASE SQL AVG SCALE <numeric value>

By default, the result of division and the AVG and MEDIAN aggregate functions has the same type as the aggregated type of the values. This includes the scale. The scale specified with this property is used if it is larger than the scale of the operation. For example, the average of 5 and 10 is 7 by default, but 7.50 if the scale is specified as 2. The result of 7/3 is 2 by default but 2.33 if the scale is specified as 2.

Standard SQL considers this behaviour implementation dependent. Some databases use a default scale larger than zero.

The property is 0 by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.avg_scale.

SET DATABASE SQL DOUBLE NAN

set database sql double nan

<set database sql double nan> ::= SET DATABASE SQL DOUBLE NAN { TRUE | FALSE }

When the property is TRUE, division of a floating point value (a DOUBLE value) by zero raises an exception. When the property is FALSE, a Java Double.NaN, POSITIVE_INFINITY or NEGATIVE_INFINITY value is returned.

Standard SQL requires an exception to be raised.

The property is TRUE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.double_nan.

SET DATABASE SQL NULLS FIRST

set database sql nulls first

<set database sql nulls first> ::= SET DATABASE SQL NULLS FIRST { TRUE | FALSE }

When the property is TRUE, nulls appear before values in result sets with ORDER BY. When set FALSE, nulls appear after the values. Some databases, including PostgreSQL, Oracle and MS SQL Server, return nulls after the values.

The property is TRUE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.nulls_first.

SET DATABASE SQL SYNTAX DB2

set database sql syntax DB2

<set database sql syntax DB2 statement> ::= SET DATABASE SQL SYNTAX DB2 { TRUE | FALSE }

This property, when set TRUE, enables support for some elements of DB2 syntax. Single-row SELECT statements (SELECT <expression list> without the FROM clause) are supported and treated as the SQL Standard equivalent, VALUES <expression list>. The DUAL table is supported, as well as the ROWNUM pseudo-column. BINARY type definitions such as VARCHAR(L) FOR BIT DATA are supported. Empty DEFAULT clauses in column definitions are supported.

The property is FALSE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.syntax_db2.

SET DATABASE SQL SYNTAX MSS

set database sql syntax MSS

<set database sql syntax MSS statement> ::= SET DATABASE SQL SYNTAX MSS { TRUE | FALSE }

This property, when set TRUE, enables support for some elements of SQLServer syntax. Single-row SELECT statements (SELECT <expression list> without the FROM clause) are supported and treated as the SQL Standard equivalent, VALUES <expression list>. The parameters of CONVERT() function are switched in this mode.

The property is FALSE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.syntax_mss.

SET DATABASE SQL SYNTAX MYS

set database sql syntax MYS

<set database sql syntax MYS statement> ::= SET DATABASE SQL SYNTAX MYS { TRUE | FALSE }

This property, when set TRUE, enables support for some elements of MySQL syntax. The TEXT data type is translated to LONGVARCHAR.

In CREATE TABLE statements, [NOT NULL | NULL] can be used immediately after the column type name and before the DEFAULT clause. AUTO_INCREMENT is translated to the GENERATED BY DEFAULT AS IDENTITY clause.

Single-row SELECT statements (SELECT <expression list> without the FROM clause) are supported and treated as the SQL Standard equivalent, VALUES <expression list>.

The property is FALSE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.syntax_mys.

SET DATABASE SQL SYNTAX ORA

set database sql syntax ORA

<set database sql syntax ORA statement> ::= SET DATABASE SQL SYNTAX ORA { TRUE | FALSE }

This property, when set TRUE, enables support for some elements of Oracle syntax. The DUAL table is supported, together with ROWNUM, NEXTVAL and CURRVAL syntax and semantics.

The non-standard types are translated to supported standard types. BINARY_DOUBLE and BINARY_FLOAT are translated to DOUBLE. LONG RAW and RAW are translated to VARBINARY with long or medium length limits. LONG and VARCHAR2 are translated to VARCHAR with long or medium length limits. NUMBER is translated to DECIMAL. Some extra type conversions and no-arg functions are also allowed in this mode.

The property is FALSE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.syntax_ora.

SET DATABASE SQL SYNTAX PGS

set database sql syntax PGS

<set database sql syntax PGS statement> ::= SET DATABASE SQL SYNTAX PGS { TRUE | FALSE }

This property, when set TRUE, enables support for some elements of PosgtreSQL syntax. The TEXT data type is translated to LONGVARCHAR, while the SERIAL data types is translated to BIGINT together with GENERATED BY DEFAULT AS IDENTITY.

Single-row SELECT statements (SELECT <expression list> without the FROM clause) are supported and treated as the SQL Standard equivalent, VALUES <expression list>.

The functions NEXTVAL(<sequence name string>), CURRVAL(<sequence name string>) and LASTVAL() are supported in this compatibility mode.

The property is FALSE by default.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property sql.syntax_pgs.

SET DATABASE REFERENTIAL INTEGRITY

set database referential integrity statement

<set database referential integrity statement> ::= SET DATABASE REFERENTIAL INTEGRITY { TRUE | FALSE }

This command enables or disables the enforcement of referential integrity constraints (foreign key constraints), check constraints apart from NOT NULL and execution of triggers. By default, all constraints are checked.

The only legitimate use of this statement is before importing large amounts of external data into tables that have existing FOREIGN KEY constraints. After import, the statement must be used again to enable constraint enforcement.

If you are not sure the data conforms to the constraints, run queries to verify all rows conform to the FOREIGN KEY constraints and take appropriate actions for the rows that do not conform.

A query example to return the rows in a foreign key table that have no parent is given below:

Example 11.5. Finding foreign key rows with no parents after a bulk import

  SELECT * FROM foreign_key_table LEFT OUTER JOIN primary_key_table 
    ON foreign_key_table.fk_col = primary_key_table.pk_col WHERE primary_key_table.pk_col IS NULL

Only a user with the DBA role can execute this statement.

Cache, Persistence and Files Settings

These statements control the memory and other settings for database persistence.

SET FILES BACKUP INCREMENT

set files backup increment statement

<set files backup increment statement> ::= SET FILES BACKUP INCREMENT { TRUE | FALSE }

Older versions of HSQLDB perform a backup of the .data file before its contents are modified and the whole .data file is saved in a compressed form when a CHECKPOINT or SHUTDOWN is performed. This takes a long time when the size of the database exceeds 100 MB or so (on an average 2010 computer, you can expect a backup speed of 20MB per second or more).

The alternative is backup in increments, just before some part of the .data file is modified. In this mode, no backup is performed at CHECKPOINT or SHUTDOWN. This mode is preferred for large databases which are opened and closed frequently.

The default mode is TRUE. If the old method of backup is preferred, the mode can be set FALSE.

Warning: The old, non-incremental setting, FALSE, shouldn't be used at all when the data file is larger than 4GB. If it is used, the data file is not fully backed up and can result in corruption. The zip compression method is used in this mode and it is limited to 4GB size.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.inc_backup.

SET FILES CACHE ROWS

set files cache rows statement

<set files cache rows statement> ::= SET FILES CACHE ROWS <unsigned integer literal>

Sets the maximum number of rows (of CACHED tables) held in the memory cache. The default is 50000 rows.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.cache_rows.

SET FILES CACHE SIZE

set files cache size statement

<set files cache size statement> ::= SET FILES CACHE SIZE <unsigned integer literal>

Sets maximum amount of data (of CACHED tables) in kilobytes held in the memory cache. The default is 10000 kilobytes. Note the amount of memory used is larger than this amount, which does not account for Java object size overheads.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.cache_size.

SET FILES DEFRAG

set files defrag statement

<set files defrag statement> ::= SET FILES DEFRAG <unsigned integer literal>

Sets the threshold for performing a DEFRAG during a checkpoint. The <unsigned integer literal> is the percentage of abandoned space in the *.data file. When a CHECKPOINT is performed either as a result of the .log file reaching the limit set by SET FILES LOG SIZE m, or by the user issuing a CHECKPOINT command, the amount of space abandoned since the database was opened is checked and if it is larger than specified percentage, a CHECKPOINT DEFRAG is performed instead of a CHECKPOINT.

The default is 0, which indicates no DEFRAG. Useful values are between 10 to 50.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.defrag_limit.

SET FILES LOG

set files log statement

<set files log statement> ::= SET FILES LOG { TRUE | FALSE }

Sets logging of database operations on or off. Turning logging off is for special usage, such as temporary cache usage. The default is TRUE.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.log_data.

SET FILES LOG SIZE

set files log size statement

<set files log size statement> ::= SET FILES LOG SIZE <unsigned integer literal>

Sets the maximum size in MB of the *.log file to the specified value. The default maximum size is 50 MB. If the value is zero, no limit is used for the size of the file. When the size of the file reaches this value, a CHECKPOINT is performed and the the *.log file is cleared to size 0.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.log_size.

SET FILES NIO

set files nio

<set files nio statement> ::= SET FILES NIO { TRUE | FALSE }

Sets the access method of the .data file. The default is TRUE and uses the Java nio classes to access the file via memory-mapped buffers.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.nio_data_file.

SET FILES NIO SIZE

set files nio size

<set files nio size statement> ::= SET FILES NIO SIZE <unsigned integer literal>

Sets The maximum size of .data file in megabytes that can use the nio access method. When the file gets larger than this limit, non-nio access methods are used. Values 64, 128, 256, 512, 1024 and larger multiples of 512 can be used. The default is 256MB.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.nio_max_size.

SET FILES WRITE DELAY

set files write delay statement

<set files write delay statement> ::= SET FILES WRITE DELAY {{ TRUE | FALSE } | <seconds value> | <milliseconds value> MILLIS}

Set the WRITE DELAY property of the database. The WRITE DELAY controls the frequency of file sync for the log file. When WRITE_DELAY is set to FALSE or 0, the sync takes place immediately at each COMMIT. WRITE DELAY TRUE performs the sync once every 0.5 seconds (which is the default). A numeric value can be specified instead.

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.

A write delay of 0 impacts performance in high load situations, as the engine has to wait for the file system to catch up.

To avoid this, you can set write delay down to 10 milliseconds.

Each time the SET FILES WRITE DELAY statement is executed with any value, a sync is immediately performed.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection properties hsqldb.write_delay and hsqldb.write_delay_millis.

SET FILES SCALE

set files scale

<set files scale statement> ::= SET FILES SCALE <scale value>

Changes the scale factor for the .data file. The default scale is 8 and allows 16GB of data storage capacity. The scale can be increased in order to increase the maximum data storage capacity. The scale values 8, 16, 32, 64, 128, 256, 512, 1024 are allowed. Scale value 1024 allows a maximum capacity of 2 TB.

This command can be used only when there is no data in CACHED tables. This is equivalent to the connection property hsqldb.cache_file_scale.

The scale factor indicates the size of the unit of storage of data in bytes. For example, with a scale factor of 128, a row containing a small amount of data will use 128 bytes. Larger rows may use multiple units of 128 bytes.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.cache_file_scale.

SET FILES LOB SCALE

set files lob scale

<set files lob scale statement> ::= SET FILES LOB SCALE <scale value>

Changes the scale factor for the .lobs file. The scale is interpreted in kilobytes. The default scale is 32 and allows 64TB of lob data storage capacity. The scale can be reduced in order to improve storage efficiency. If the lobs are a lot smaller than 32 kilobytes, reducing the scale will reduce wasted space. The scale values 1, 2, 4, 8, 16, 32 are allowed. For example if the average size of lobs is 4 kilobytes, the default scale of 32 will result in 28KB wasted space for each lob. Reducing the lob scale to 2 will result in average 1KB wasted space for each lob.

This command can be used only when there is no lob in the database.

Only a user with the DBA role can execute this statement.

This is equivalent to the connection property hsqldb.lob_file_scale.

SET FILES SCRIPT FORMAT

set files script format

<set files script format statement> ::= SET FILES SCRIPT FORMAT { TEXT | COMPRESSED }

Changes the compression setting for database scripts. The default is text. Using COMPRESSED results in the storage of the .script file in gzip compressed form. Using this command causes a CHECKPOINT.

Only a user with the DBA role can execute this statement.

SET TABLE TYPE

set table type

<set table type statement> ::= SET TABLE <table name> TYPE { MEMORY | CACHED }

Changes the storage type of an existing table between CACHED and MEMORY types.

Only a user with the DBA role can execute this statement.

Authentication Settings

Two settings are available for authentication control.

When the default password authentication is used, the passwords can be checked for complexity according to administrative rules

SET DATABASE PASSWORD CHECK FUNCTION

set database password check function

<set database password check function statement> ::= SET DATABASE PASSWORD CHECK FUNCTION { <routine body> | NONE }

The routine body is the body of a function that has a VARCHAR parameter and returns a BOOLEAN. This function checks the PASSWORD submitted as parameter and returns TRUE if it conforms to complexity checks, or FALSE, if it does not.

The <routine body> can be an SQL block or an external Java function reference. This is covered in the SQL-Invoked Routines chapter

To disable this mechanism, the token NONE can be specified instead of the <routine body>.

Only a user with the DBA role can execute this statement.

In the examples below, an SQL function and a Java function are used.

SET DATABASE PASSWORD CHECK FUNCTION
  BEGIN ATOMIC
    IF CHAR_LENGTH(PASSWORD) > 6 THEN
      RETURN TRUE;
    ELSE 
      RETURN FALSE;
    END IF;
  END

SET DATABASE PASSWORD CHECK FUNCTION EXTERNAL NAME 'CLASSPATH:org.anorg.access.AccessClass.accessMethod'

// the Java method is defined like this
public static boolean accessMethod(String param) {
    return param != null && param.length > 6;
}

It is possible to replace the default password authentication completely with a function that uses external authentication servers, such as LDAP. This function is called each time a user connects to the database.

SET DATABASE AUTHENTICATION FUNCTION

set database authentication function

<set database authentication function statement> ::= SET DATABASE AUTHENTICATION FUNCTION { <external body reference> | NONE }

The routine body is an external Java function reference. This function has three String parameters. The first parameter is the unique name of the database, the second parameter the user name, and the third parameter the password.

External authentication can be used in two different patterns. In the first pattern, user names must be stored in the database. In the second pattern, user names shouldn't be stored in the database and any names that are stored in the database are ignored.

In both patterns, the username and password are checked by the authentication function. If the function throws a runtime exception then authentication fails.

In the first pattern, the function always returns null if authentication is successful.

In the second pattern, the function returns a list of role names that have been granted to the user. These roles must match the ROLE objects that have been defined in the database.

The Java function should return an instance of org.hsqldb.jdbc.JDBCArrayBasic constructed with a String[] argument that contains the role names.

Only a user with the DBA role can execute this statement.

SET DATABASE AUTHENTICATION FUNCTION EXTERNAL NAME 'CLASSPATH:org.anorg.access.AccessClass.accessExernalMethod'

// the Java method is defined like this
public static java.sql.Array accessExternalMethod(String database, String user, String password) {
    if (externalCheck(database, user, password) {
        return null;
    }
    throw new RuntimeException("failed to authenticate");
}

$Revision: 4864 $