$Revision: 6692 $
Copyright 2002-2024 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.
2024-10-25
Table of Contents
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.
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 access a Server from outside the main application and perform backups and other maintenance operations.
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.
There are three types of database, mem:,
file: and res:. The
mem: type is stored all in memory and not
persisted to file. The file: type is persisted to
file. The res: type is also based on files, but
the files are loaded from the classpath, similar to resource and class
files. Changes to the data in file: databases are
persisted, unless the database is readonly
, or
files_readonly
(using optional property settings).
Changes to res: databases are not
persisted.
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. The SHUTDOWN command must be used to close the database
before making this change.
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.
With readonly databases, it is still possible to insert and delete rows in TEMP tables.
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.
A res: catalog, is a set of database
files on the classpath (inside a jar or alongside class files). The
database is opened with a URL in the form of
jdbc:hsqldb:res:<database path>
. These
databases are always files_readonly
and have the
same restrictions as files_readonly
file: catalogs.
CACHED tables and LOBS in these catalogs are readonly. It is not possible to create new LOBs in these catalogs, but you can use existing LOBs in new rows.
These options are useful for running application tests which operate on a predefined dataset.
In mem: catalogs, MEMORY tables without persistence are supported alongside TEXT tables with persistence but CACHED table are not supported.
In file: and res: catalogs, MEMORY, CACHED and TEXT tables are all supported with persistence.
TEXT tables are designed for special applications where the data has to be in an interchangeable format, such as CSV (comma separated values). Rows of data can be inserted into TEXT tables and existing rows can be updated or deleted. For data that is updated a lot, it is better to use a MEMORY or CACHED table to improve reliability in case of system crash. TEXT tables can also be used to open CSV or DSV (delimiter separated values) files in order to copy the data into other types of table.
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.
HyperSQL 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 terabyte
figures. By default, a minimum 32 KB is allocated to each LOB. You can
reduce this if your LOBs are generally smaller.
LOB data should be stored 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.
With all-in-memory mem: databases, the memory space for deleted lobs is not reused by default, as there is no automatic checkpoint. Automatic checkpoints can be activated by setting the LOG SIZE property to a value larger than zero. When the accumulated size of deleted lobs reaches the LOG SIZE setting (in megabytes) an automatic checkpoint is performed and the memory space is released.
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 IDs, 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.PARTS TYPE CACHED SET TABLE SYSTEM_LOBS.LOB_IDS TYPE CACHED
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 64GB (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.
In desktop deployments, virus checker programs may interfere with the creation and modification of database files. You should exclude the directory containing the database files from virus checking.
HyperSQL supports PRIMARY KEY, UNIQUE and FOREIGN KEY constraints, which can span multiple columns.
The engine creates indexes internally to support PRIMARY KEY, UNIQUE and FOREIGN KEY constraints: a unique index is created for each PRIMARY KEY or UNIQUE constraint; a non-unique index is created for each FOREIGN KEY constraint.
From version 2.6, you can extend the non-unique index for a FORIEGN
KEY constraint to cover extra columns. For example, if you have a FOREIGN
KEY constraint defined on INVOICES(CUSTOMER_ID)
, you
can add an extra column such as INVOICE_DATE
to the
FOREIGN KEY index. This speeds up queries with conditions such as:
WHERE customer_id = 456 and invoice_date =
'2020-02-02'
. See the ALTER CONSTRAINT statement for
syntax.
HyperSQL allows you to define indexes on single or multiple columns with the CREATE INDEX statement. You should not create duplicate indexes on the same column sets covered by constraints. This will result in unnecessary memory and speed overheads. See the discussion on memory use in the Deployment Guide chapter for more information.
Indexes are crucial for adequate query speed. When range or equality
conditions are used e.g. SELECT ... WHERE acol > 10 AND bcol =
0
, an index should exist on one of the columns that has a
condition. In this example, the bcol
column is the best
candidate. HyperSQL always uses the best condition and index. If there are
two indexes, one on acol, and another on bcol, it will choose the index on
bcol.
Queries always return results whether indexes exist or not, but they
return much faster when an index exists. As a rule of thumb, HSQLDB is
capable of internal processing of queries at around 1,000,000 rows per
second. Any query that runs into several seconds is clearly accessing many
thousands of rows. The query should be checked and indexes should be added
to the relevant columns of the tables if necessary. The EXPLAIN
PLAN FOR <query>
statement can be used to see which
indexes are used to process the query.
When executing a DELETE or UPDATE statement, the engine needs to find the rows that are to be deleted or updated. If there is an index on one of the columns in the WHERE clause, it is often possible to start directly from the first candidate row. Otherwise all the rows of the table have to be examined.
Indexes are even more important in joins between multiple tables.
SELECT ... FROM t1 JOIN t2 ON t1.c1 = t2.c2
is
performed by taking rows of t1 one by one and finding a matching row in
t2. If there is no index on t2.c2, then for each row of t1 all the rows of
t2 must be checked. Whereas with an index on t2.c2, a matching row can be
found in a fraction of the time. If the query also has a condition on t1,
e.g., SELECT ... FROM t1 JOIN t2 ON t1.c1 = t2.c2 WHERE t1.c3 =
4
then an index on t1.c3 would eliminate the need for checking
all the rows of t1 one by one, and will reduce query time to less than a
millisecond per returned row.
So if t1 and t2 each contain 10,000 rows, the query without indexes involves checking 100,000,000 row combinations. With an index on t2.c2, this is reduced to 10,000 row checks and index lookups. With the additional index on t2.c2, only about 4 rows are checked to get the first result row.
Note that in HSQLDB an index on multiple columns can be used
internally as an index on the first column in the list. For example:
CONSTRAINT name1 UNIQUE (c1, c2, c3)
means there is
the equivalent of CREATE INDEX name2 ON atable(c1);
. So
you do not need to specify an extra index if you need one on the first
column of the list.
In HyperSQL, a multi-column index will speed up queries that contain
joins or values on the first n columns of the index. You need NOT declare
additional individual indexes on those columns unless you use queries that
search only on a subset of the columns, excluding the first column. For
example, rows of a table that has a PRIMARY KEY or UNIQUE constraint on
three columns or simply an ordinary index on those columns can be found
efficiently when values for all three columns, or the first two columns,
or the first column, are specified in the WHERE clause. For example,
SELECT ... FROM t1 WHERE t1.c1 = 4 AND t1.c2 = 6 AND t1.c3 = 8
will use an index on t1(c1,c2,c3)
if it
exists.
A multi-column index will not speed up queries on the second or third column only. The first column must be specified in the JOIN .. ON or WHERE conditions.
Sometimes query speed depends on the order of the tables in the JOIN
.. ON or FROM clauses. For example, the second query below should be
faster with large tables (provided there is an index on
TB.COL3
). The reason is that TB.COL3
can be evaluated by index lookup and reduce the matching rows if it
applies to the first table:
-- TB is a very large table with only a few rows where TB.COL3 = 4 SELECT * FROM TA JOIN TB ON TA.COL1 = TB.COL2 AND TB.COL3 = 4; SELECT * FROM TB JOIN TA ON TA.COL1 = TB.COL2 AND TB.COL3 = 4;
The general rule is to put first the table that has a narrowing condition on one of its columns. In certain cases, HyperSQL reorders the joined tables if it is obvious that this will introduce a narrowing condition. This is discussed in the next section.
HyperSQL features automatic, on-the-fly indexes for views and subselects that are used in a query.
Indexes are used when a LIKE condition searches from the start of the string.
Indexes are used for ORDER BY clauses if the same index is used for selection and ordering of rows. It is also possible to force the use of index for ORDER BY.
HyperSQL performs "cost-base optimisation" to changes the order of tables in a query in order to optimise processing. It computes and compares the approximate time (cost) it takes to execute the query with different table orders and chooses the one with the least costs. This happens only when one of the tables has a narrowing condition and reordering does not change the result of the query.
HyperSQL optimises queries to use indexes, for all types of range and equality conditions, including IS NULL and NOT NULL conditions. Conditions can be in join or WHERE clauses, including all types of joins.
In addition, HyperSQL will use an index (if one exists) for IN conditions, whether constants, variables, or subqueries are used on the right-hand side of the IN predicate. Multicolumn IN conditions can also use an index.
HyperSQL can always use indexes when several conditions are combined with the AND operator, choosing a condition which can use an index. This now extended to all equality conditions on multiple columns that are part of an index.
HyperSQL will also use indexes when several conditions are combined with the OR operator and each condition can use an index (each condition may use a different index). For example, if a huge table has two separate columns for first name and last name, and each of these columns has an index, a query such as the following example will use the indexes and complete in a short time:
-- TC is a very large table SELECT * FROM TC WHERE TC.FIRSTNAME = 'John' OR TC.LASTNAME = 'Smith' OR TC.LASTNAME = 'Williams'
Each subquery is considered a separate SELECT statement and uses indexes when they are available.
In each SELECT statement, at least one index per table can be used if there is a query conditions that can use the index. When conditions on a table are combined with the OR operator, and each condition can use an index, multiple indexes per table are used.
HyperSQL optimises simple row count queries in the form of
SELECT COUNT(*) FROM <table>
and returns the
result immediately (this optimisation may not always take place in MVCC
mode).
HyperSQL can use an index on a column for SELECT
MAX(<column>) FROM <table>
and SELECT
MIN(<column>) FROM <table>
queries. There should
be an index on the <column> and the query can have a WHERE
condition on the same column. In the example below the maximum value for
the TB.COL3 below 1000000 is returned.
SELECT MAX(TB.COL3) FROM TB WHERE TB.COL < 1000000
HyperSQL can use an index for simple queries containing DISTINCT or GROUP BY to avoid checking all the rows of the table. Note that indexes are always used if the query has a condition, regardless of the use of DISTINCT or GROUP BY. This particular optimisation applies to cases in which all the columns in the SELECT list are from the same table and are covered by a single index, and any join or query condition uses this index.
For example, with the large table below, a DISTINCT or GROUP BY query to return all the last names, can use an the index on the TC.LASTNAME column. Similarly, a GROUP BY query on two columns can use an index that covers the two columns.
-- TC is a very large table SELECT DISTINCT LASTNAME FROM TC WHERE TC.LASTNAME > 'F' SELECT STATE, LASTNAME FROM TC GROUP BY STATE, LASTNAME
HyperSQL can use an index on an ORDER BY clause if all the columns
in ORDER BY are in a single-column or multi-column index (in the exact
order). This is important if there is a LIMIT n (or FETCH n ROWS ONLY)
clause. In this situation, the use of index allows the query processor
to access only the number of rows specified in the LIMIT clause, instead
of building the whole result set, which can be huge. This also works for
joined tables when the ORDER BY clause is on the columns of the first
table in a join. Indexes are used in the same way when ORDER BY
... DESC
is specified in the query. Note that unlike some
other RDBMS, HyperSQL does not need or create DESC indexes. It can use
any ordinary, ascending index for ORDER BY ...
DESC
.
If there is an equality or range condition (e.g. EQUALS, GREATER THAN) condition on the columns specified in the ORDER BY clause, the index is still used.
In the two examples below, the index on TA.COL3 is used and only up to 1000 rows are processed and returned.
-- TA is a very large table with an index on TA.COL3 SELECT * FROM TA JOIN TB ON TA.COL2 = TB.COL1 WHERE TA.COL3 > 40000 ORDER BY TA.COL3 LIMIT 1000; SELECT * FROM TA JOIN TB ON TA.COL2 = TB.COL1 WHERE TA.COL3 > 40000 AND TA.COL3 < 100000 ORDER BY TA.COL3 DESC LIMIT 1000;
But if the query contains a condition on another indexed column in the table, this may take precedence and no index may be used for ORDER BY. In this case USING INDEX can be added to the end of the query to force the use of the index for the LIMIT operation.
In the example below there is an index on TA.COL1 as well as the
index on TA.COL3. Normally the index on TA.COL1 is used, but the USING
INDEX hint results in the index on TB.COL3 to be used for selecting the
first 1000 rows. Supposing there are 10 million rows in the table and 1
million rows have COL1 = 'SENT'
, when the index on
COL1 is used, one million rows are read before ORDER BY and LIMIT are
applied. But with the USING INDEX approximately about 10 times the 1000
rows are read and filtered until the 1000 row target is reached.
-- TA is a very large table with an index on TA.COL3 and a separate index on TA.COL1 SELECT * FROM TA JOIN TB ON TA.COL2 = TB.COL1 WHERE TA.COL1 = 'SENT' ORDER BY TA.COL3 LIMIT 1000 USING INDEX;
HyperSQL's persistence mechanism has proven reliable, as the last critical issue was fixed in 2008.
There are further enhancements in the latest version.
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 HyperSQL 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 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 workarounds which are
recommended for Sun JVMs and later OpenJDK ones. This does not apply to
other JVMs. In such environments, it is therefore recommended to stress
test the CHECKPOINT DEFRAG operation and the shutting down and restarting
the database inside the same Java process extensively with NIO. Use of NIO
is not essential and can be turned off if necessary.
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 time
interval may be lost. The default time interval is 0.5 second. 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.
A database is opened when the first connection is successfully
made. It remains open until the SHUTDOWN
command is
issued. If the connection property shutdown=true is used for the first
connection to the database, the database is shutdown when the last
connection is closed. Otherwise the database remains open and will
accept the next connection attempt.
The SHUTDOWN
command shuts down the database
properly and allows the database to be reopened quickly. This command
may take some seconds as it saves all the modified data in the
.script
and .data
files. Variants
of SHUTDOWN
such as SHUTDOWN
COMPACT
and SHUTDOWN SCRIPT
can be used
from time to time to reduce the overall size of the database files.
Another variant is SHUTDOWN IMMEDIATELY
which ensures
all changes to data are stored in the .log
file but
does not save the changes in .script
and
.data
files. The shutdown is performed quickly but
the database will take much longer to reopen.
During the lifetime of the database the checkpoint operation may
be performed from time to time. The SET FILES LOG SIZE <
value >
setting and its equivalent URL property determine
the frequency of automatic checkpoints. An online backup also performs a
checkpoint when the backup is not a hot backup. A checkpoint can be
performed by the user at any time using the
CHECKPOINT
statement. The main purpose of checkpoints
is to reduce the total size of database files and to allow a quick
restart in case the database is closed without a proper shutdown. The
CHECKPOINT DEFRAG
variant compacts the
.data
file in a similar way to SHUTDOWN
COMPACT
does. Obviously, this variant takes much longer than a
normal CHECKPOINT
. A database setting allows a
CHECKPOINT DEFRAG
to be performed automatically when
wasted space in the .data
file exceeds the specified
percentage.
In a multi-user application, automatic or user-initiated
checkpoints are delayed until all other sessions have committed or
rolled back. During a checkpoint, other sessions cannot access the
database tables but can access the INFORMATION_SCHEMA
system tables.
HyperSQL 2.5 and later allows you to store data in temporal system-versioned tables. The additional syntax elements for CREATE TABLE and ALTER TABLE allow creating system-versioned tables and adding system versioning to existing tables. These are covered in the Schemas and Database Objects chapter. Only CACHED or MEMORY tables can be system-versioned.
System versioning has three main uses.
During development and testing of applications, system-versioning keeps all the changes made by a set of integration tests. Correctness of the data change statements can be verified.
Retention of data for regulatory requirements can be safely managed by the database engine, without the need for additional complexity in the application.
Time travel queries allow views of the data at any point in the past, as well as views of the changes over a given period.
Replicated distributed databases with system versioning on all tables allow changes to data to be synchronized between the replicas.
All DML statements that modify the table data see only the current rows of the table, you cannot modify the old version history of rows. SELECT statements can include a FOR SYSTEM_TIME clause to access historic data in a given timestamp range. This is discussed in Data Access and Change chapter.
Old historic rows can be removed up to a chosen point of time with a special form of the TRUNCATE statement. This is covered in the Data Access and Change chapter.
An example of a system-versioned table follows:
Example 11.2. Creating a system-versioned table
CREATE TABLE codedata ( code CHAR(10) not null, id SMALLINT not null , primary key (ID), PS TIMESTAMP GENERATED ALWAYS AS ROW START, PE TIMESTAMP GENERATED ALWAYS AS ROW END, PERIOD FOR SYSTEM_TIME(PS,PE) ) WITH SYSTEM VERSIONING
Replicated databases are databases with multiple copies in different locations that contain the same table structure and data. With system-versioned tables, a set of replicas can be synchronized.
Data changes to a replica after a point of time can be written to a script. The script can then be applied to another replica. See the syntax details of PERFORM SCRIPT statement in this chapter. The timestamp used for export is the timestamp at the point of last synchronization. For example, if the first EXPORT occurs at TIMESTAMP '2020-10-01 10:10:10' and the script is later imported into the replica, the second EXPORT should use that timestamp to ensures old histories that have already been exported are not exported again. The import will skip duplicates and there is no harm in exporting from an earlier timestamp, except it will take longer to import.
-- on one replica, the changes from the given UTC timestamp are exported to a file PERFORM EXPORT SCRIPT FOR DATABASE VERSIONING DATA FROM '2022-03-21 08:00:00' TO '/data/diff_file' -- on another replica, the diff file is imported and the changes are merged into the database PERFORM IMPORT SCRIPT VERSIONING DATA FROM '/data/diff_file'
Synchronization of tables with BLOB and CLOB columns is not currently possible as the export script does not contain the LOB data. This may be supported in a future version.
For a replica set where only one replica is updated and the others are only read, this method of replication has no conflict. For replica sets where each replica is updated, the database schema and usage must account for this. During import, when there is a conflicts, the conflicting change is not applied and is instead written to another file to be reviewed.
Data for all CACHED tables is stored in the .data
file. With a new recommended setting, HyperSQL 2.5 and later allocates
separate blocks of the data file to different CACHED tables. This is
recommended for all databases with a data file larger than a few
megabytes. This method has the following advantages:
When a table is dropped, all its data allocation blocks are freed and become available for reuse.
When old rows are deleted in bulk, the space is immediately released and reused.
When many rows are updated or deleted over a long period, the disk space occupied by the old versions of the rows is eventually freed.
The following statement should be executed once to start the table spaces for the whole database:
SET FILES SPACE TRUE
The alternative is to include the corresponding connection property on the JDBC connection URL that creates the database. For example:
jdbc:hsqldb:file:<database
path>;hsqldb.files_space=true
Then the statement below should be executed for each CACHED table that will have its own space:
SET TABLE <table name> NEW SPACE
If the above statement is not executed, the table is stored in common blocks shared by a number of tables.
If either of the above statements is executed again after the first time, it does not change any settings.
It is better to set any table that is known to grow larger than a few thousand rows its own space before any data is stored.
A database with table spaces uses a minimum of 4 to 6 megabytes for
its data structures to keep track of file space use. The size overhead is
then about half a percent of the size of the .data
file as it
grows larger.
The size of the file block is 2MB when the
hsqldb.cache_file_scale
is the default 32 (the size doubles
as the scale doubles). It is possible to reduce the block size to 1MB for
databases that contain many small tables that use their own, dedicated
spaces. The statement SET FILES SPACE 1
can be executed
instead of SET FILES SPACE TRUE
for a reduced block
size.
As the tables grow in size, more blocks are allocated to their spaces. These blocks are allocated from the freed file blocks if there are any available. The INFORMATION_SCHEMA.SYSTEM_TABLESTATS provides information on the space usage of table spaces. In this table, the SPACE_ID column contains the space id for the table. The value 1 is used for the space allocated by the system to its data structures. The value 7 is for tables that use the common space.
Conversion of existing databases to use table spaces is simple. If
the SET FILES SPACE TRUE
command is executed when there are
already some rows in any CACHED table, the change does not happen
immediately. In this case, the table spaces are created only when
CHECKPOINT DEFRAG, SHUTDOWN COMPACT, or SHUTDOWN SCRIPT is executed. Among
these commands, CHECKPOINT DEFRAG will also automatically allocate a
separate space to each table that is larger than a certain size.
In a database with table spaces enabled, the SET TABLE
<table name> NEW SPACE
command immediately applies a separate
space to the table, whether it is empty or has data..
The integrity of the indexes and table data can be checked with a statement. This applies to CACHED tables only. Individual tables or all tables can be checked.
PERFORM CHECK TABLE PUBLIC.CUSTOMER INDEX [ AND FIX ]
PERFORM CHECK ALL TABLE INDEX [ AND FIX ]
The command reads and compares all the rows and lists the size of each table and the size of each index on the table. If an index is damaged, the list shows the number of rows that could be read as different from the number of rows in the table. With large tables, it can take a long time to complete.
It is possible to execute the command with the addition of
AND FIX
to the end. If some indexes have been damaged
but at least one index on a table is undamaged, this should fix the
problem and if the command is run again, it should show no damage.
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 to back up a database. 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 features commands to back up the database files into a
single .tar
or .tar.gz
file archive,
or alternatively as copies of the database files. 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.
It is not recommended to back up the database file with an external file backup program while the database is running. The resulting backup will probably be inconsistent and not useful for restoring the database
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 back up the database as a
single .tar.gz
file to the given directory. This type
of backup performs a checkpoint immediately before backing up the
files.
BACKUP DATABASE TO <directory name> BLOCKING [ AS FILES ]
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/'
.
Normal backup may take a long time with very large databases. Hot backup may be used in those situations. This type of backup does not perform a checkpoint and allows access to the database while backup is in progress.
BACKUP DATABASE TO <directory name> NOT BLOCKING [ AS FILES ]
If you add AS FILES to the statements, the database files are backed up as separate files in the directory, without any gzip compression or tar archiving.
See the next section under Statements for details about the command and its options. See the sections below about restoring a backup.
The DbBackup
class is used from the
command-line to make offline backups and to restore backups. Here is how
to see all options for DbBackup
.
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.4. Offline Backup Example
java -cp hsqldb.jar org.hsqldb.lib.tar.DbBackupMain --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:.
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.5. Listing a Backup with DbBackup
java -cp hsqldb.jar org.hsqldb.lib.tar.DbBackupMain --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.
You use DbBackup
on your operating system
command line to restore a catalog from a backup.
Example 11.6. Restoring a Backup with DbBackup
java -cp hsqldb.jar org.hsqldb.lib.tar.DbBackupMain --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). After restoring the database, you can connect to it as
usual.
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.
Four elements are involved in specifying the cryptography mode of operation.
A cipher is identified by a transformation string of the form "algorithm/mode/padding" or simply "algorithm". Note The latter form uses the provider default mode and padding.
A key is represented as a hexadecimal string.
An optional initialization vector, for modes of operation that use an IV, is represented as a hexadecimal string.
An optional provider is the fully qualified class name of the cipher provider.
The parameters, including the name of the cipher and the key, are all specified in the database connection URL No key or other parameter is stored in the database files.
First, a key must be created for the desired cipher and configuration using an external tool, such as openssl, or by calling the HyperSQL 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 generated random values.
As an example, a call to CRYPT_KEY('Blowfish', null) returned the string, '604a6105889da65326bf35790a923932'. To create a new database with this key, the URL below is used:
jdbc:hsqldb:file:<database
path>;crypt_key=604a6105889da65326bf35790a923932;crypt_type=blowfish
HyperSQL works with any symmetric cipher and transformation that may be available from the JVM. Some modes of operations require an initialization vector (IV) to be passed in as a hex string. This hex string can be generated using an external tool, such as openssl, or randomly generated by the user.
jdbc:hsqldb:file:<database
path>;crypt_key=604a6105889da65326bf35790a923932;crypt_iv=9AB7A109507CD27BEADA2AE59BCEEF08;crypt_type=AES/CBC/PKCS5Padding
The fourth property name is crypt_provider. This is specified only when the provider is not the default provider.
Note: Do not use these example crypt_key or crypt_iv values in production. Create your own random values.
The files that are encrypted include the
.script
, .data
,
.backup
and .log
files. From
version 2.5, the .lobs
file is also encrypted by
default and the blobs and clobs are both compressed and encrypted. You
can override this with the property
crypt_lobs=false on the URL. Earlier versions of
HSQLDB did not support encrypted lobs, and in some versions the default
for this property was false. You will need to set the property to false
to open those databases.
Although the details of external tools are outside the scope of this document, openssl may be used to generate sufficiently random keys and initialization vectors for a given crypt_type using the following syntax:
openssl enc -aes-128-cbc -k RANDOM_PASSPHRASE -P -md
sha256
General operations on an encrypted database are performed the same as with any database. However, some operations are significantly slower than with the equivalent clear text 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 for encrypted databases have been discussed at length in HyperSQL 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. Peeking 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 clear text dump of an encrypted database. Therefore, encryption is generally effective only when the users who have access to the crypt key are trusted.
Database operations can be monitored at different levels using internal HyperSQL capabilities or add-ons.
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 HyperSQL and had to be integrated into HyperSQL at code level. The latest versions can be added on as a proxy in a much simpler fashion.
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 a small impact on speed. So you should only use this
for debugging. Four levels of SQL logging are supported.
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 application deployment, as it provides an ongoing record of
database operations.
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.
The extent of logged messages is controlled with the SET
DATABASE EXTERNAL EVENT LOG LEVEL
statement, described in this
chapter.
As the default JDK logging framework has several shortcomings,
HyperSQL can configure this logging framework for better operation. If
you want HyperSQL to configure the JDK logging framework, you should
include the system level property
hsqldb.reconfig_logging=true
in your
environment.
HyperSQL has extensive security features which are implemented at different levels and covered in different chapters of this guide.
The server can use SSL and IP address access control lists. See the HyperSQL Network Listeners (Servers) chapter.
You can define a system property to allow the database engine access to a limited set of Java static methods that are on the classpath, This is only necessary if you want to use those Java static methods as SQL routines See Securing Access to Classes in the SQL-Invoked Routines chapter.
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 or want to load and save files directly to the file system as BLOB or CLOB. See the Text Tables chapter.
The database files can be encrypted. Discussed in this chapter.
Within the database, the DBA privileges are required for system and maintenance jobs.
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. HyperSQL supports table level, column level, and row level privileges. See the Access Control chapter.
You can define a password complexity check function for new and changed passwords. This is covered below under Authentication Settings.
You can use external authentication such as LDAP 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.
The default settings are generally adequate for embedded use of the database in single-user applications. For servers on the host that are accessed from the same machine or accessed within a network, and especially for those accessed from outside the network, additional security settings must be used. This is the minimum list of changes you need to make:
Change the admin password. Change the admin name (the default is SA) as well for extra security.
Create a non-admin user for normal database access and grant the required SELECT, INSERT, UPDATE and DELETE privileges to this user. Connect with this user's credentials from the application.
Set up SSL and IP address access control on the Server.
Restrict the execution of multiple statements with
SET DATABASE SQL RESTRICT EXEC TRUE
.
Backup the database regularly and store the backups in a different location than the machine running the Server.
The default settings for server and web server do not use SSL or IP access control lists. These features are enabled programmatically, 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 programmatically 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 programmatically 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 was always SA in older versions of HyperSQL, 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. You can also change the name after creating 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 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 as a hash 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
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.
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 |
SHUTDOWN IMMEDIATELY |
Saves the |
SHUTDOWN COMPACT |
This is similar to normal SHUTDOWN, but reduces the
|
SHUTDOWN SCRIPT |
This is similar to SHUTDOWN COMPACT, but it does not rewrite
the 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} [AS
FILES]
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. This type of backup is suitable for smaller
databases. With larger databases, this takes a long time. When the
SCRIPT option is no used, the backup set will consist 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.
If AS FILES is specified, the database files are copied to a directory specified by <file path> without any compression. The file path must be a directory. If the directory does not exist, it is created. The file path may be absolute or relative. If it is relative, it is interpreted as relative to the location of database files. When AS FILES is specified, SCRIPT or COMPRESSED options are not available. The backup can be performed as BLOCKING or NOT BLOCKING.
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 reopens the database.
If DEFRAG
is specified, also shrinks the
*.data
file to its minimum size. CHECKPOINT
DEFRAG
time depends on the size of the database and can take a
long time with huge databases.
A checkpoint on a multi-user database waits until all other sessions have committed or rolled back. While the checkpoint is in progress other sessions are kept waiting. Checkpoint does not close any sessions.
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.
These statements allow data to be transferred in bulk from one
database to another using files formatted in the same manner as the
.script
files.
EXPORT SCRIPT
export script statement
<export script statement> ::= PERFORM EXPORT
SCRIPT FOR DATABASE [ { STRUCTURE | DATA } ] [WITH COLUMN NAMES] TO
<single-quoted file path>
<export script table statement> ::= PERFORM
EXPORT SCRIPT FOR TABLE <table name> DATA [WITH COLUMN NAMES] TO
<single-quouted file path>
<export script for versioning statement> ::=
PERFORM EXPORT SCRIPT FOR DATABASE VERSIONING DATA FROM TIMESTAMP
<single-quoted UTC timestamp string> TO <file
name>
Writes a script containing SQL statements for the database.
The first form writes the whole database, its structure only,
or its data only to the file. When only DATABASE is specified,
everything is written out. When STRUCTURE is specified, only the
database settings and the definition of schema objects are written. When
DATA is specified, only the data in the tables is written. The optional
WITH COLUMN NAMES
clause includes the list of column
names in INSERT statements and may be useful for exporting data to other
database engines. This option should not be used for scripts that are
imported into HSQLDB with the PERFORM IMPORT SCRIPT
statement, as the script will be rejected.
The second form writes the data for one table only.
The third form writes the data in all system-versioned tables from a given UTC timestamp. This form is used for database replica synchronization, to be imported into another replica. For synchronization purposes, all system-versioned tables must have a primary key as those without are not exported. UTC timestamps are used to allow synchronization across time zones.
Only a user with the SCRIPT_OPS role can execute this statement.
EXPORT DSV
export DSV statement
<export DSV statement> ::= PERFORM EXPORT DATA
FROM TABLE <table name> TO <single-quouted text file source
string>
Writes the contents of a table as a DSV file, for example as a Comma-Seperated Values (CSV).
The destination is defined as a file path together with optional setting as defined for a TEXT table. See the Text Tables chapter for the properties.
Only a user with the SCRIPT_OPS role can execute this statement.
IMPORT SCRIPT
import script statement
<import script statement> ::= PERFORM IMPORT
SCRIPT DATA FROM <single-quoted file path> { CONTINUE | STOP |
CHECK } ON ERROR
<import script for versioning statement> ::=
PERFORM IMPORT SCRIPT VERSIONING DATA FROM <single-quoted file
path>
Imports data for database tables. The file to be imported must be a file exported with the EXPORT SCRIPT statements listed above with DATA qualifier, or strictly in the same format.
The first form is for importing data for ordinary tables. The {
CONTINUE | STOP | CHECK } ON ERROR clause determines the action when an
error occurs due to constraint violation. The CHECK option does not
insert the data, but checks each INSERT statement in the script for type
constraints such as string size limit or row constraints such as NOT
NULL. It cannot check for UNIQUE constraints. The STOP option stops the
import at the first error. The CONTINUE option writes the rows that
cannot be imported, to a file in the same location as the imported
script, with the file suffix .reject
and the
timestamp of the import, then continues the import.
The second form is for importing data for system-versioned
tables. This form of import always uses the CONTINUE option mentioned
above. When two replicas of a database exist, an EXPORT is made from one
replica and the script file is used for an IMPORT into the other
replica. The import automatically ignores any history that is already in
the table and avoid any duplication of data. Errors can arise when the
same row has been inserted, updated or deleted in both databases. In
this case, the changes for the row are not applied and are written to
the .reject
file.
Only a user with the SCRIPT_OPS role can execute this statement.
IMPORT DSV
import DSV statement
<import DSV statement> ::= PERFORM IMPORT DATA
INTO <table name> FROM <single-quoted file path> { CONTINUE
| STOP | CHECK } ON ERROR
Imports data from a DSV file into a table. The file to be imported may be a file exported with the EXPORT DSV statement listed above, or a file from another source. The source is defined as a file path together with optional setting as defined for a TEXT table. See the Text Tables chapter for the properties.
The { CONTINUE | STOP | CHECK } ON ERROR clause determines the
action when an error occurs due to constraint violation. The CHECK
option does not insert the data, but checks each line of data in the DSV
file for type constraints such as string size limit or row constraints
such as NOT NULL. It cannot check for UNIQUE constraints. The STOP
option stops the import at the first error. The CONTINUE option writes
the rows that cannot be imported, to a file in the same location as the
imported script, with the file suffix .reject
and the
timestamp of the import, then continues the import. If there is a
malformed line in the DSV file, the import is aborted with an error
message, regardless of the ON ERROR option.
Only a user with the SCRIPT_OPS role can execute this statement.
CHECK INDEX
check index statement
<check index statement> ::= PERFORM CHECK { ALL
TABLE | TABLE < table name > } INDEX [ AND FIX
]
Checks the indexes on a single CACHED table, or all the CACHED
tables in the database. It returns a list of tables and indexes with
rows counts together with any errors found. The optional AND
FIX
fixes the damaged indexes on a table if at least one index
is undamaged. If this option is used, you must perform a CHECKPOINT
after completion, otherwise the fixes will be lost.
This statements takes a long time to execute on large tables as all the rows are read again for each index. It also needs extra Java heap memory over and above normal usage.
Only a user with the DBA role can execute this statement. An example of the output is given below.
TABLE_OR_INDEX_NAME INFO -------------------------- --------------------- TABLE PUBLIC.ZIP rows 4096 SYS_IDX_SYS_PK_10092_10093 readable rows 4096 TABLE PUBLIC.TEST rows 2084352 SYS_IDX_SYS_PK_10096_10097 readable rows 2084352
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
.
After you change the collation for a database that contains
collated data, you must execute SHUTDOWN COMPACT
or
SHUTDOWN SCRIPT
in order to recreate the
indexes.
Only a user with the DBA role can execute this statement.
Collations are discussed in the Schemas and Database Objects chapter. Some examples of setting the database collation follow:
-- this collation is an ascii collation with Upper Case Comparison (coverts strings to uppercase for comparison) SET DATABASE COLLATION SQL_TEXT_UCC -- this collation is case-insensitive English SET DATABASE COLLATION "English 1" -- this collation is case-sensitive French SET DATABASE COLLATION "French 2"
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
[EXTERNAL] EVENT LOG [ SQL ] LEVEL { 0 | 1 | 2 | 3 |
4}
This statement has 3 different purposes and can be used up to three times with different options to configure various event logging operations.
When the EXTERNAL and SQL options are 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 warning events as well. Level 3 means more events, including both important and less important (normal) events. Level 4 includes even more details.
The events are logged in a file with the extension
.app.log
alongside the main database files. For
readonly and mem: databases, if the level is set
above 0, the log messages are directed to stderr, but these databases do
not generate many log messages.
This command is equivalent to the connection property hsqldb.applog.
When the EXTERNAL option is used (the SQL option is not allowed in this case), the statement configures the level of events that are logged to the JDK or Log4J logger. For example, LEVEL 2 indicates error and warning events (levels 1 and 2) are logged.
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, 2, 3 and 4 are supported. Level 1 only logs commits and rollbacks. Level 2 and above log all statements. Level 2 truncates long statements, while level 3 reports the full statement and parameter values. Level 4 add the update count or the size of the returned result set.
The logged lines are stored in a file with the extension
.sql.log
alongside the main database files.
This command is equivalent to the connection property hsqldb.sqllog.
Only a user with the DBA role can execute this statement.
From version 2.3.0, the equivalent URL properties,
hsqldb.app_log
and hsqldb.sql_log
,
can be used not only for a new database, but also when opening an
existing file database to change the event log level.
An extract from an .sql.log
file created
with log Level 3 is shown below. The numbers after the timestamp (10 and
1) show the session number. The values for prepared statement parameters
are shown in parentheses at the end of the statement.
Example 11.7. SQL Log Example
2012-11-29 10:40:40.250 10 INSERT INTO TEST_CLOB VALUES (1,'Ut enim ad minima veniam, quis nostrum exercitationem ...') 2012-11-29 10:40:40.250 1 INSERT INTO SYSTEM_LOBS.LOB_IDS VALUES(?, ?, ?, ?) (1,49,0,40) 2012-11-29 10:40:40.250 1 COMMIT 2012-11-29 10:40:40.265 1 CALL SYSTEM_LOBS.ALLOC_BLOCKS(?, ?, ?) (1,0,1) 2012-11-29 10:40:40.265 1 COMMIT
SET DATABASE GC
set database gc statement
<set database gc statement> ::= SET DATABASE GC
<unsigned integer literal>
In previous versions, an optional property which forced calls
to System.gc()
after the specified number of
row operations. This has no effect from version 2.5.
Only a user with the DBA role can execute this statement.
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.
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 TRANSACTION ROLLBACK ON INTERRUPT
set database transaction rollback on interrupt statement
<set database transaction rollback on interrupt
statement> ::= SET DATABASE TRANSACTION ROLLBACK ON INTERRUPT { TRUE
| FALSE }
When the user application interrupts a thread that is executing a HyperSQL statement, the engine resets the interrupted flag on the thread. Setting this property to TRUE changes the behaviour and the transaction is rolled back when the interrupt is detected. 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 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 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.
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 RESTRICT EXEC
set database sql restrict exec statement
<set database sql restrict exec statement> ::=
SET DATABASE SQL RESTRICT EXEC { TRUE | FALSE }
Restricts or allows execution of SQL commands consisting of
multiple statements in a single string. The property also disallows or
allows the use of
java.sql.Statement.executeQuery()
for any DDL
or DML statement.
This property is FALSE
by default. SQL
Standard and JDBC require restriction to a single statement. It is
advisable to restrict execution.
Only a user with the DBA role can execute this statement.
This is equivalent to the connection property sql.restrict_exec.
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; 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; 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 CHARACTER LITERAL
set database sql character literal
<set database sql character literal statement>
::= SET DATABASE SQL CHARACTER LITERAL { TRUE | FALSE
}
When the property is TRUE
, the data type of
character literal strings is CHARACTER
. When the
property is FALSE
the data type is
VARCHAR
.
Setting this property FALSE
results in
strings not padded with spaces in CASE WHEN
expressions that have multiple literal alternatives.
SQL Standard requires the CHARACTER
type.
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.char_literal.
SET DATABASE SQL TRUNCATE TRAILING
set database sql truncate trailing
<set database sql truncate trailing> ::= SET
DATABASE SQL TRUNCATE TRAILING { TRUE | FALSE }
By default, this property is TRUE
, Whan a
string that is longer than the maximum size of a column is inserted,
spaces at the end are removed to reduce the length of the string to the
maximum size of the column. If this is not possible, an exception is
raised.
When the property is set to FALSE
, no
truncation take place and an exception is always raised. This behaviour
is common to some other database engines.
SQL Standard requires the default 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.truncate_trailing.
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 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 NULLS ORDER
set database sql nulls order
<set database sql nulls order> ::= SET DATABASE
SQL NULLS ORDER { TRUE | FALSE }
When NULLS FIRST or NULLS LAST is used explicitly in the ORDER BY clause, this property is ignored.
When the property is TRUE
, nulls appear
according to the value of NULL FIRST property as described
above.
When set FALSE
, nulls appear according to
the value of NULLS FIRST property when DESC is not used in the ORDER BY
clause. But if DESC is used, the position of nulls is reversed. Some
databases, including MySQL and Oracle, return nulls in this manner when
DESC is used in ORDER BY.
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_order.
SET DATABASE SQL IGNORECASE
set database sql ignorecase
<set database sql ignorecase> ::= SET DATABASE
SQL IGNORECASE { TRUE | FALSE }
This property is FALSE
by default and should
only be used in special circumstances where compatibility with a
different database is required.
When the property is TRUE
, all declarations
of VARCHAR
columns in tables or other database
objects are converted to VARCHAR_IGNORECASE
. This has
a global effect on the database, unlike the SET
IGNORECASE
statement which applies only to the current
session.
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.ignore_case.
SET DATABASE SQL LOWER CASE IDENTIFIER
set database sql lower case identifier
<set database sql lower case identifier> ::= SET
DATABASE SQL LOWER CASE IDENTIFIER { TRUE | FALSE }
This property is FALSE
by default and should
only be used in special circumstances where additional compatibility
with MySQL or PostgreSQL is required.
When the property is TRUE
, the names of
column, tables and schemas are returned from JDBC
ResultSetMetaData
methods in lowercase instead of
uppercase if the database objects were created as unquoted identifiers.
Quoted identifier names are still returned in the original
case.
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.lowercase_ident.
SET DATABASE SQL LIVE OBJECT
set database sql live object
<set database sql live object> ::= SET DATABASE
SQL LIVE OBJECT { TRUE | FALSE }
This property is FALSE
by default and can
only be used in mem: databases.
When the property is FALSE
, all java objects
stored in a column of type OTHER
are serialized. When
the property is FALSE
, objects are not serialized at
all.
This is equivalent to the connection property sql.live_object.
SET DATABASE SQL SYS INDEX NAMES
set database sql sys index names
<set database sql sys table names statement> ::=
SET DATABASE SQL SYS INDEX NAMES { TRUE | FALSE }
This property, when set TRUE, changes the naming method for system generated indexes that are used to support UNIQUE and FOREIGN KEY constraints. By default, the names of those indexes are generated as strings with SYS_ prefixes. When the property is set TRUE, the names will be the same as the constraint names.
Changing the property does not affect the names of indexes for the constraints that have already been defined. After a restart of the database all system-generated indexes are named according to the setting for this property.
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.sys_index_names.
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.8. 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.
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 }
Before any part of the .data
file is
modified, the original contents are stored in the
.backup
file. At CHECKPOINT or SHUTDOWN the latest
data is fully saved and the .backup
file is
deleted.
In older versions, this command allowed an alternative method of backup that is no longer supported. From version 2.5.1 this command is still accepted but has no effect.
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 the specified percentage, a CHECKPOINT DEFRAG
is performed instead of a CHECKPOINT. As the DEFRAG operation uses a lot
of memory and takes a long time with large databases, setting the
threshold well above zero is suitable for databases that are around than
500 MB or more.
The default is 0, which indicates no DEFRAG. Useful values are between 30 to 60.
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 32 and allows 64GB of data storage capacity. The
scale can be increased in order to increase the maximum data storage
capacity. The scale values 16, 32, 64, 128, 256, 512, 1024 are allowed.
Scale value 1024 allows a maximum capacity of 2 TB.
This command should be used before data is inserted into CACHED TABLES. It can also be used when there is some data in CACHED tables but then it has no effect until a SHUTDOWN COMPACT or SHUTDOWN SCRIPT is performed. 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.
When the data file already exists, you must perform SHUTDOWN COMPACT or SHUTDOWN SCRIPT after changing the scale. Otherwise the change will be forgotten.
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 LOB COMPRESSED
set files lob compressed
<set files lob compressed statement> ::= SET
FILES LOB COMPRESSED { TRUE | FALSE }
By default, lobs are not compressed for storage. When this
setting is TRUE
, all BLOB and CLOB values stored in
the database are compressed. Compression reduces the storage size but
increases the access time.
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_compressed.
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
.scrip
t file in gzip compressed form. Using this
command causes a CHECKPOINT.
Only a user with the DBA role can execute this statement.
SET FILES SPACE
set files space
<set files space statement> ::= SET FILES SPACE
TRUE
Enables use of table spaces for CACHED tables. Each table is allocated space in blocks. The size of each block in megabytes is equal to the data file scale divided by 16. The default data file scale is 32 so the default size of each block is 2 MB. See the SET TABLE NEW SPACE statement below.
Only a user with the DBA role can execute this statement.
SET TABLE NEW SPACE
set table new space
<set table new space statement> ::= SET TABLE
<table name> NEW SPACE
Sets the named table to use its own space blocks within the
.data
file. Use of table spaces should be enabled
with the SET FILES SPACE statement above, before this statement is
executed.
Only a user with the DBA role can execute this statement.
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: 6787 $