Chapter 9. SQL Syntax

The Hypersonic SQL Group

Fred Toussi

HSQLDB Development Group

Peter Hudson

HSQLDB Development Group

Joe Maher

HSQLDB Development Group

Edited by

Blaine Simpson

$Date: 2007/02/19 21:15:47 $

Table of Contents

Notational Conventions Used in this Chapter
SQL Commands
ALTER INDEX
ALTER SEQUENCE
ALTER SCHEMA
ALTER TABLE
ALTER USER
CALL
CHECKPOINT
COMMIT
CONNECT
CREATE ALIAS
CREATE INDEX
CREATE ROLE
CREATE SCHEMA
CREATE SEQUENCE
CREATE TABLE
CREATE TRIGGER
CREATE USER
CREATE VIEW
DELETE
DISCONNECT
DROP INDEX
DROP ROLE
DROP SEQUENCE
DROP SCHEMA
DROP TABLE
DROP TRIGGER
DROP USER
DROP VIEW
EXPLAIN PLAN
GRANT
INSERT
REVOKE
ROLLBACK
SAVEPOINT
SCRIPT
SELECT
SET AUTOCOMMIT
SET DATABASE COLLATION
SET CHECKPOINT DEFRAG
SET IGNORECASE
SET INITIAL SCHEMA
SET LOGSIZE
SET MAXROWS
SET PASSWORD
SET PROPERTY
SET READONLY
SET REFERENTIAL INTEGRITY
SET SCHEMA
SET SCRIPTFORMAT
SET TABLE INDEX
SET TABLE READONLY
SET TABLE SOURCE
SET WRITE DELAY
SHUTDOWN
UPDATE
Schema object naming
Data Types
SQL Comments
Stored Procedures / Functions
Built-in Functions and Stored Procedures
SQL Expression

HSQLDB version 1.8.0 supports the SQL statements and syntax described in this chapter.

Notational Conventions Used in this Chapter

[A] means A is optional.

{ B | C } means either B or C must be used.

[{ B | C }] means either B or C may optionally be used, or nothing at all.

( and ) are the actual characters '(' and ')' used in statements.

UPPERCASE words are keywords

SQL Commands

ALTER INDEX[2]

ALTER INDEX <indexname> RENAME TO <newname>;

Index names can be changed so long as they do not conflict with other user-defined or sytem-defined names.

ALTER SEQUENCE[2]

ALTER SEQUENCE <sequencename> RESTART WITH <value>;

Resets the next value to be returned from the sequence.

ALTER SCHEMA[2]

ALTER SCHEMA <schemaname> RENAME TO <newname>;

Renames the schema as specified. All objects of the schema will hereafter be accessible only with the new schema name.

Requires Administrative privileges.

ALTER TABLE[2]

ALTER TABLE <tablename> ADD [COLUMN] <columnname> Datatype
    [(columnSize[,precision])] [{DEFAULT <defaultValue> |
    GENERATED BY DEFAULT AS IDENTITY (START WITH <n>[, INCREMENT BY <m>])}] |
    [[NOT] NULL] [IDENTITY] [PRIMARY KEY]
    [BEFORE <existingcolumn>];

Adds the column to the end of the column list. The optional BEFORE <existingcolumn> can be used to specify the name of an existing column so that the new column is inserted in a position just before the <existingcolumn>.

It accepts a columnDefinition as in a CREATE TABLE command. If NOT NULL is specified and the table is not empty, then a default value must be specified. In all other respects, this command is the equivalent of a column definition statement in a CREATE TABLE statement.

If an SQL view includes a SELECT * FROM <tablename> in its select statement, the new column is added to the view. This is a non-standard feature which is likely to change in the future.

ALTER TABLE <tablename> DROP [COLUMN] <columnname>;

Drops the column from the table. Will drop any single-column primary key or unique constraint on the column as well. The command will not work if there is any multiple key constraint on the column or the column is referenced in a check constraint or a foreign key.

It will also fail if an SQL view includes the column.

ALTER TABLE <tablename> ALTER COLUMN <columnname> RENAME TO <newname> 

Changes a column name.

ALTER TABLE <tablename> ALTER COLUMN <columnname> SET DEFAULT <defaultvalue>};

Adds the specified default value to the column. Use NULL to remove a default.

ALTER TABLE <tablename> ALTER COLUMN <columnname> SET [NOT] NULL

Sets or removes a NOT NULL constraint for the column.

ALTER TABLE <tablename> ALTER COLUMN <columnDefinition>;

This form of ALTER TABLE ALTER COLUMN accepts a columnDefinition as in a CREATE TABLE command, with the following restrictions.

Restrictions

  • The column must be already be a PK column to accept an IDENTITY definition.
  • If the column is already an IDENTITY column and there is no IDENTITY definition, the existing IDENTITY attribute is removed.
  • The default expression will be that of the new definition, meaning an existing default can be dropped by ommission, or a new default added.
  • The NOT NULL attribute will be that of the new definition (similar to previous item).
  • Depending on the type of change, the table may have to be empty for the command to work. It always works when the type of change is possible in general and the individual existing values can all be converted.
ALTER TABLE <tablename> ALTER COLUMN <columnname>
    RESTART WITH <new sequence value>

This form is used exclusively for IDENTITY columns and changes the next automatic value for the identity sequence.

ALTER TABLE <tablename> ADD [CONSTRAINT <constraintname>]
    CHECK (<search condition>);

Adds a check constraint to the table. In the current version, a check constraint can reference only the row being inserted or updated.

ALTER TABLE <tablename> ADD [CONSTRAINT <constraintname>] UNIQUE (<column list>);

Adds a unique constraint to the table. This will not work if there is already a unique constraint covering exactly the same <column list>.

This will work only if the values of the column list for the existing rows are unique or include a null value.

ALTER TABLE <tablename> ADD [CONSTRAINT <constraintname>]
    PRIMARY KEY (<column list>);

Adds a primary key constraint to the table, using the same constraint syntax as when the primary key is specified in a table definition.

ALTER TABLE <tablename>
    ADD [CONSTRAINT <constraintname>] FOREIGN KEY (<column list>)
    REFERENCES <exptablename> (<column list>)
    [ON {DELETE | UPDATE} {CASCADE | SET DEFAULT | SET NULL}];

Adds a foreign key constraint to the table, using the same constraint syntax as when the foreign key is specified in a table definition.

This will fail if for each existing row in the referring table, a matching row (with equal values for the column list) is not found in the referenced tables.

ALTER TABLE <tablename> DROP CONSTRAINT <constraintname>;

Drop a named unique, check or foreign key constraint from the table.

ALTER TABLE <tablename> RENAME TO <newname>;

ALTER USER[2]

ALTER USER <username> SET PASSWORD <password>;

Changes the password for an existing user. Password must be double quoted. Use "" for an empty password.

DBA's may change users' base default schema name with the comand

ALTER USER <username> SET INITIAL SCHEMA <schemaname>;
This is the schema which database object names will resolve to for this user, unless overridden as explained in Schema object naming. For reasons of backwards compatibility, the initial schema value will not be persisted across database shutdowns until HSQLDB version 1.8.1. (I.e., INITIAL SCHEMA settings will be lost upon database shutdown with HSQLDB versions lower than version 1.8.1).

Only an administrator may use these commands.

CALL

CALL Expression;

Any expression can be called like a stored procedure, including, but not only Java stored procedures or functions. This command returns a ResultSet with one column and one row (the result) just like a SELECT statement with one row and one column.

See also: Stored Procedures / Functions, SQL Expression.

CHECKPOINT

CHECKPOINT [DEFRAG[2]];

Closes the database files, rewrites the script file, deletes the log file and opens the database.

If DEFRAG is specified, this command also shrinks the .data file to its minimal size.

See also: SHUTDOWN, SET LOGSIZE.

COMMIT

COMMIT [WORK];

Ends a transaction and makes the changes permanent.

See also: ROLLBACK, SET AUTOCOMMIT, SET LOGSIZE.

CONNECT

CONNECT USER <username> PASSWORD <password>;

Connects to the database as a different user. Password should be double quoted. Use "" for an empty password.

See also: GRANT, REVOKE.

CREATE ALIAS

CREATE ALIAS <function> FOR <javaFunction>;

Creates an alias for a static Java function to be used as a Stored Procedure. The function must be accessible from the JVM in which the database runs. Example:

    CREATE ALIAS ABS FOR "java.lang.Math.abs";

Note

The CREATE ALIAS command just defines the alias. It does not validate existence of the target method or its containing class. To validate the alias, use it.

See also: CALL, Stored Procedures / Functions.

CREATE INDEX

CREATE [UNIQUE] INDEX <index> ON <table> (<column> [DESC] [, ...]) [DESC];

Creates an index on one or more columns in a table.

Creating an index on searched columns may improve performance. The qualifier DESC can be present for command compatibility with other databases but it has no effect. Unique indexes can be defined but this is deprecated. Use UNIQUE constraints instead. The name of an index must be unique within the whole database.

See also: CREATE TABLE, DROP INDEX.

CREATE ROLE[2]

CREATE ROLE <rolename>;

Creates the named role with no members. Requires Administrative privileges.

CREATE SCHEMA[2]

CREATE SCHEMA <schemaname> AUTHORIZATION <grantee>
    [<createStatement> [<grantStatement>] [...];

Creates the named schema, with ownership of the specified authorization. The authorization grantee may be a database user or a role.

Optional (nested) CREATE and GRANT statements can be given only for new objects in this new schema. Only the last nested statement should be terminated with a semicolon, because the first semicolon encountered after "CREATE SCHEMA" will end the CREATE SCHEMA command. In the example below, a new schema, ACCOUNTS, is created, then two tables and a view are added to this schma and some rights on these objects are granted.

    CREATE SCHEMA ACCOUNTS AUTHORIZATION DBA
        CREATE TABLE AB(A INTEGER, ...)
        CREATE TABLE CD(C CHAHR, ...)
        CREATE VIEW VI AS SELECT ...
        GRANT SELECT TO PUBLIC ON AB
        GRANT SELECT TO JOE ON CD;
Note that this example consists of one CREATE SCHEMA statement which is terminated by a semicolon.

Requires Administrative privileges.

CREATE SEQUENCE[2]

CREATE SEQUENCE <sequencename> [AS {INTEGER | BIGINT}]
    [START WITH <startvalue>] [INCREMENT BY <incrementvalue>];

Creates a sequence. The default type is INTEGER. The default start value is 0 and the increment 1. Negative values are not allowed. If a sequence goes beyond Integer.MAXVALUE or Long.MAXVALUE, the next result is determined by 2's complement arithmetic.

The next value for a sequence can be included in SELECT, INSERT and UPDATE statements as in the following example:

SELECT [...,] NEXT VALUE FOR <sequencename> [, ...] FROM <tablename>;

In the proposed SQL 200n and in the current version, there is no way of retreiving the last returned value of a sequence.

CREATE TABLE

CREATE [MEMORY | CACHED | [GLOBAL] TEMPORARY | TEMP [2] | TEXT[2]] TABLE <name>
    ( <columnDefinition> [, ...] [, <constraintDefinition>...] )
    [ON COMMIT {DELETE | PRESERVE} ROWS];

Creates a tables in memory (default) or on disk and only cached in memory. If the database is all-in-memory, both MEMORY and CACHED forms of CREATE TABLE return a MEMORY table while the TEXT form is not allowed.

Components of a CREATE TABLE command

columnDefinition
columnname Datatype [(columnSize[,precision])]
    [{DEFAULT <defaultValue> |
    GENERATED BY DEFAULT AS IDENTITY
    (START WITH <n>[, INCREMENT BY <m>])}] |
    [[NOT] NULL] [IDENTITY] [PRIMARY KEY]

Default values that are allowed are constant values or certain SQL datetime functions.

Allowed Default Values in Column Definitions

  • For character column, a single-quoted string or NULL. The only SQL function that can be used is CURRENT_USER.

  • For datetime columns, a single-quoted DATE, TIME or TIMESTAMP value or NULL. Or a datetime SQL function such as CURRENT_DATE, CURRENT_TIME, CURRENT_TIMESTAMP, TODAY, NOW. Each function is allowed for a certain datetime type.

  • For BOOLEAN columns, the literals FALSE, TRUE, NULL.

  • For numeric columns, any valid number or NULL.

  • For binary columns, any valid hex string or NULL.

Only one identity column is allowed in each table. Identity columns are autoincrement columns. They must be of INTEGER or BIGINT type and are automatically primary key columns (as a result, multi-column primary keys are not possible with an IDENTITY column present). Using the long SQL syntax the (START WITH <n>) clause specifies the first value that will be used. The last inserted value into an identity column for a connection is available using the function IDENTITY(), for example (where Id is the identity column):

INSERT INTO Test (Id, Name) VALUES (NULL,'Test');
    CALL IDENTITY();
constraintDefinition
[CONSTRAINT <name>]
    UNIQUE ( <column> [,<column>...] ) |
    PRIMARY KEY ( <column> [,<column>...] ) |
    FOREIGN KEY ( <column> [,<column>...] )
    REFERENCES <refTable> ( <column> [,<column>...]) 
    [ON {DELETE | UPDATE}
    {CASCADE | SET DEFAULT | SET NULL}][2] |
    CHECK(<search condition>)[2]

Both ON DELETE and ON UPDATE clauses can be used in a single foreign key definition.

search condition

A search condition is similar to the set of conditions in a WHERE clause. In the current version of HSQLDB, the conditions for a CHECK constraint can only reference the current row, meaning there should be no SELECT statement. Sample table definitions with CHECK constraints are in TestSelfCheckConstraints.txt. This file is in the /hsqldb/testrun/hsqldb/ directory of the zip.

General syntax limitations

HSQLDB databases are initially created in a legacy mode that does not enforce column size and precision. You can set the property: sql.enforce_strict_size=true to enable this feature. When this property has been set, Any supplied column size and precision for numeric and character types (CHARACTER and VARCHAR) are enforced. Use the command, SET PROPERTY "sql.enforce_strict_size" TRUE once before defining the tables.

NOT NULL constraints can be part of the column definition only. Other constraints cannot be part of the column definition and must appear at the end of the column definition list.

TEMPORARY TABLE contents for each session (connection) are emptied by default at each commit or rollback. The optional qualifier ON COMMIT PRESERVE ROWS can be used to keep the rows while the session is open. The default is ON COMMIT DELETE ROWS.

See also: DROP TABLE.

CREATE TRIGGER[2]

CREATE TRIGGER <name> {BEFORE | AFTER} {INSERT | UPDATE | DELETE} ON <table>
    [FOR EACH ROW] [QUEUE n] [NOWAIT] CALL <TriggerClass>;

TriggerClass is an application-supplied class that implements the org.hsqldb.Trigger interface e.g. "mypackage.TrigClass". It is the fire method of this class that is invoked when the trigger event occurs. You should provide this class, which can have any name, and ensure that this TriggerClass is present in the classpath which you use to start hsqldb.

Since 1.7.2 the implementation has been changed and enhanced. When the 'fire' method is called, it is passed the following arguments:

    fire (String name, String table, Object row1[], Object row2[])

where 'row1' and 'row2' represent the 'before' and 'after' states of the row acted on, with each column being a member of the array. The mapping of members of the row arrays to database types is specified in Data Types. For example, BIGINT is represented by a java.lang.Long Object. Note that the number of elements in the row arrays could be larger than the number of columns by one or two elements. Never modify the last elements of the array, which are not part of the actual row.

If the trigger method wants to access the database, it must establish its own JDBC connection. This can cause data inconsistency and other problems so it is not recommended. The jdbc:default:connection: URL is not currently supported.

Implementation note:

If QUEUE 0 is specified, the fire method is execued in the same thread as the database engine. This allows trigger action to alter the data that is about to be stored in the database. Data can be checked or modified in BEFORE INSERT / UPDATE + FOR EACH ROW triggers. All table constraints are then enforced by the database engine and if there is a violation, the action is rejected for the SQL command that initiated the INSERT or UPDATE. There is an exception to this rule, that is with UPDATE queries, referential integrity and cascading actions resulting from ON UPDATE CASCASE / SET NULL / SET DEFAULT are all performed prior to the invocation of the trigger method. If an invalid value that breaks referential integrity is inserted in the row by the trigger method, this action is not checked and results in inconsistent data in the table.

Alternatively, if the trigger is used for external communications and not for checking or altering the data, a queue size larger than zero can be specified. This is in the interests of not blocking the database's main thread as each trigger will run in a thread that will wait for its firing event to occur. When this happens, the trigger's thread calls TriggerClass.fire. There is a queue of events waiting to be run by each trigger thread. This is particularly useful for 'FOR EACH ROW' triggers, when a large number of trigger events occur in rapid succession, without the trigger thread getting a chance to run. If the queue becomes full, subsequent additions to it cause the database engine to suspend awaiting space in the queue. Take great care to avoid this situation if the trigger action involves accessing the database, as deadlock will occur. This can be avoided either by ensuring the QUEUE parameter makes a large enough queue, or by using the NOWAIT parameter, which causes a new trigger event to overwrite the most recent event in the queue. The default queue size is 1024. Note also that the timing of trigger method calls is not guaranteed, so applications should implement their own synchronization measures if necessary.

With a non-zero QUEUE parameter, if the trigger methods modifies the 'row2' values, these changes may or may not affect the database and will almost certainly result in data inconsistency.

Please refer to the code for org.hsqldb.sample.Trigger and org.hsqldb.sample.TriggerSample for more information on how to write a trigger class.

See also: DROP TRIGGER.

CREATE USER

CREATE USER <username> PASSWORD <password> [ADMIN];

Creates a new user or new administrator in this database. Password must be double quoted. Empty password can be made using "". You can change a password afterwards using a ALTER USER[2] command.

Only an administrator can do this.

See also: CONNECT, GRANT, REVOKE. ALTER USER[2],

CREATE VIEW[2]

CREATE VIEW <viewname>[(<viewcolumn>,..) AS SELECT ... FROM ... [WHERE Expression]
[ORDER BY orderExpression [, ...]]
[LIMIT <limit> [OFFSET <offset>]];

A view can be thought of as either a virtual table or a stored query. The data accessible through a view is not stored in the database as a distinct object. What is stored in the database is a SELECT statement. The result set of the SELECT statement forms the virtual table returned by the view. A user can use this virtual table by referencing the view name in SQL statements the same way a table is referenced. A view is used to do any or all of these functions:

  • Restrict a user to specific rows in a table. For example, allow an employee to see only the rows recording his or her work in a labor-tracking table.

  • Restrict a user to specific columns. For example, allow employees who do not work in payroll to see the name, office, work phone, and department columns in an employee table, but do not allow them to see any columns with salary information or personal information.

  • Join columns from multiple tables so that they look like a single table.

  • Aggregate information instead of supplying details. For example, present the sum of a column, or the maximum or minimum value from a column.

Views are created by defining the SELECT statement that retrieves the data to be presented by the view. The data tables referenced by the SELECT statement are known as the base tables for the view. In this example, is a view that selects data from three base tables to present a virtual table of commonly needed data:

    CREATE VIEW mealsjv AS
      SELECT m.mid mid, m.name name, t.mealtype mt, a.aid aid,
             a.gname + ' ' + a.sname author, m.description description,
             m.asof asof
        FROM meals m, mealtypes t, authors a
       WHERE m.mealtype = t.mealtype
        AND m.aid = a.aid;

You can then reference mealsjv in statements in the same way you would reference a table:

    SELECT * FROM mealsjv;

A view can reference another view. For example, mealsjv presents information that is useful for long descriptions that contain identifiers, but a short list might be all a web page display needs. A view can be built that selects only specific mealsjv columns:

    CREATE VIEW mealswebv AS SELECT name, author FROM mealsjv;

The SELECT statement in a VIEW definition should return columns with distinct names. If the names of two columns in the SELECT statement are the same, use a column alias to distinguish between them. A list of new column names can always be defined for a view.

    CREATE VIEW aview (new_name, new_author) AS
      SELECT name, author
      FROM mealsjv

See also: SQL Expression, SELECT[2], DROP VIEW[2].

DELETE

DELETE FROM table [WHERE Expression];

Removes rows in a table.

See also: SQL Expression, INSERT, SELECT[2].

DISCONNECT

DISCONNECT;

Closes this connection. It is not required to call this command when using the JDBC interface: it is called automatically when the connection is closed. After disconnecting, it is not possible to execute other queries (including CONNECT) with this connection.

See also: CONNECT.

DROP INDEX

DROP INDEX index [IF EXISTS];

Removes the specified index from the database. Will not work if the index backs a UNIQUE of FOREIGN KEY constraint.

See also: CREATE INDEX.

DROP ROLE[2]

DROP ROLE <rolename>;

Removes all members from specified role, then removes the role itself.

DROP SEQUENCE[2]

DROP SEQUENCE <sequencename> [IF EXISTS] [RESTRICT | CASCADE];

Removes the specified sequence from the database. When IF EXIST is used, the statement returns without an error if the sequence does not exist. The RESTRICT option is in effect by default, meaning that DROP will fail if any view reference the sequence. Specify the CASCADE option to silently drop all dependent database objects.

DROP SCHEMA[2]

DROP SCHEMA <schemaname> [RESTRICT | CASCADE];

Removes the specified schema from the database. The RESTRICT option is in effect by default, meaning that DROP will fail if any objects such as tables or sequences have been defined in the schema. Specify the CASCADE option to silently drop all database objects in the schema.

Requires Administrative privileges.

DROP TABLE

DROP TABLE <table> [IF EXISTS] [RESTRICT | CASCADE];

Removes a table, the data and indexes from the database. When IF EXIST is used, the statement returns without an error even if the table does not exist.

The RESTRICT option is in effect by default, meaning that DROP will fail if any tables or views refer to this table. Specify the CASCADE option to silently drop all dependent views, and to drop any foreign key constraint that links this table with other tables.

See also:

CREATE TABLE.

DROP TRIGGER

DROP TRIGGER <trigger>;

Removes a trigger from the database.

See also: CREATE TRIGGER[2].

DROP USER

DROP USER <username>;

Removes a user from the database.

Only an administrator do this.

See also: CREATE USER.

DROP VIEW[2]

DROP VIEW <viewname> [IF EXISTS] [RESTRICT | CASCADE];

Removes a view from the database. When IF EXIST is used, the statement returns without an error if the view does not exist. The RESTRICT option is in effect by default, meaning that DROP will fail if any other view refers to this view. Specify the CASCADE option to silently drop all dependent views.

See also: CREATE VIEW[2].

EXPLAIN PLAN

EXPLAIN PLAN FOR { SELECT ... | DELETE ... | INSERT ... | UPDATE ..};

EXPLAIN PLAN FOR can be used with any query to get a detailed list of the elements in the execution plan.

This list includes the indexes used for performing the query and can be used to optimise the query or to add indexes to tables.

GRANT

GRANT { SELECT | DELETE | INSERT | UPDATE | ALL } [,...]
ON { table | CLASS "package.class" } TO <grantee>;
GRANT <rolename> [,...] TO <grantee>[2];

<grantee> is either a user name, a role name, or PUBLIC. PUBLIC means all users.

The first form of the GRANT command assigns privileges to a grantee for a table or for a class. To allow a user to call a Store Procedure static function, the right ALL must be used. Examples:

    GRANT SELECT ON Test TO GUEST;
    GRANT ALL ON CLASS "java.lang.Math.abs" TO PUBLIC;

Warning

Even though the command is GRANT ALL ON CLASS, you must specify a static method name. You are actually granting access to a static method, not to a class.

The second form of the GRANT command gives the specified <grantee> membership in the specified role.

Requires Administrative privileges.

See also: REVOKE, CREATE USER, CREATE ROLE[2].

INSERT

INSERT INTO table [( column [,...] )]
{ VALUES(Expression [,...]) | SelectStatement};

Adds one or more new rows of data into a table.

REVOKE

REVOKE { SELECT | DELETE | INSERT | UPDATE | ALL } [,...]
ON { table | CLASS "package.class" } FROM <grantee>;
REVOKE <rolename> [,...] FROM <grantee>[2];

<grantee> is either a user name, a role name, or PUBLIC. PUBLIC means all users.

The first form of the REVOKE command withdraws privileges from a grantee for a table or for a class.

The second form of the REVOKE command withdraws membership of the specified <grantee> from the specified role.

Both forms require Administrative privileges.

See also: GRANT.

ROLLBACK

ROLLBACK [TO SAVEPOINT <savepoint name>[2] |  WORK}];

ROLLBACK used on its own, or with WORK, undoes changes made since the last COMMIT or ROLLBACK.

ROLLBACK TO SAVEPOINT <savepoint name> undoes the change since the named savepoint. It has no effect if the savepoint is not found.

See also: COMMIT.

SAVEPOINT[2]

SAVEPOINT <savepoint name>;

Sets up a SAVEPOINT for use with ROLLBACK TO SAVEPOINT.

See also: COMMIT.

SCRIPT

SCRIPT ['file'];

Creates an SQL script describing the database. If the file is not specified, a result set containing only the DDL script is returned. If the file is specified then this file is saved with the path relative to the machine where the database engine is located.

Only an administrator may do this.

SELECT[2]

SELECT [{LIMIT <offset> <limit> | TOP <limit>}[2]][ALL | DISTINCT]
{ selectExpression | table.* | * } [, ...]
[INTO [CACHED | TEMP  | TEXT][2] newTable]
FROM tableList
[WHERE Expression]
[GROUP BY Expression [, ...]]
[HAVING Expression]
[{ UNION [ALL | DISTINCT] | {MINUS [DISTINCT] | EXCEPT [DISTINCT] } |
INTERSECT [DISTINCT] } selectStatement]
[ORDER BY orderExpression [, ...]]
[LIMIT <limit> [OFFSET <offset>]];

Retrieves information from one or more tables in the database.

Components of a SELECT command

tableList
table [{CROSS | INNER | LEFT OUTER | RIGHT OUTER}
    JOIN table ON Expression] [, ...]
table
{ (selectStatement) [AS] label | tableName}
selectExpression
{ Expression | COUNT(*) | {
    COUNT | MIN | MAX | SUM | AVG | SOME | EVERY |
    VAR_POP | VAR_SAMP | STDDEV_POP | STDDEV_SAMP
} ([ALL | DISTINCT][2]] Expression) } [[AS] label]

If DISTINCT is specified, only one instance of several equivalent values is used in the aggregate function. Except COUNT(*), all aggregate functions exclude NULL values. The type of the returned value for SUM is subject to deterministic widenning to ensure lossless results. The returned value type for COUNT is INTEGER, for MIN, MAX and AVG it is the same type as the column, for SOME and EVERY it is BOOLEAN. For VAR_POP, VAR_SAMP, STDDEV_POP and STDDEV_SAMP statistical functions, the type is always DOUBLE. These statistical functions do not allow ALL or DISTINCT qualifiers.

If CROSS JOIN is specified no ON expression is allowed for the join.

orderExpression
{ columnNr | columnAlias | selectExpression }
    [ASC | DESC]
LIMIT n m

Creates the result set for the SELECT statement first and then discards the first n rows (OFFSET) and returns the first m rows of the remaining result set (LIMIT). Special cases: LIMIT 0 m is equivalent to TOP m or FIRST m in other RDBMS's; LIMIT n 0 discards the first n rows and returns the rest of the result set.

LIMIT m OFFSET n

This form is used at the end of the SELECT statement. The OFFSET term is optional.

TOP m

Equivalent to LIMIT 0 m.

UNION and other set operations

Multiple SELECT statements joined with UNION, EXCEPT and INTERSECT are possible. Each SELECT is then treated as a term, and the set operation as an operator in an expression. The expression is evaluated from left to right but INTERSECT takes precedence over the rest of the operators and is applied first. You can use parentheses around any number of SELECT statements to change the evaluation order.

See also: INSERT, UPDATE, DELETE.

SET AUTOCOMMIT

SET AUTOCOMMIT { TRUE | FALSE };

Switches on or off the connection's auto-commit mode. If switched on, then all statements will be committed as individual transactions. Otherwise, the statements are grouped into transactions that are terminated by either COMMIT or ROLLBACK. By default, new connections are in auto-commit mode. This command should not be used directly. Use the JDBC equivalent method, Connection.setAutoCommit(boolean autocommit).

SET DATABASE COLLATION[2]

SET DATABASE COLLATION <double quoted collation name>;

Each database can have its own collation. Sets the collation from the set of collations in the source for org.hsqldb.Collation.

Once this command has been issued, the database can be opened in any JVM and will retain its collation.

SET CHECKPOINT DEFRAG[2]

SET CHECKPOINT DEFRAG <size>;

The parameter size is the megabytes 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 LOGSIZE size", or by the user issuing a CHECKPOINT command, the amount of space abandoned during the session is checked and if it is larger than size, a CHECKPOINT DEFRAG is performed instead of a checkpoint.

SET IGNORECASE

SET IGNORECASE { TRUE | FALSE };

Disables (ignorecase = true) or enables (ignorecase = false) the case sensitivity of text comparison and indexing for new tables. By default, character columns in new databases are case sensitive. The sensitivity must be switched before creating tables. Existing tables and their data are not affected. When switched on, the data type VARCHAR is set to VARCHAR_IGNORECASE in new tables. Alternatively, you can specify the VARCHAR_IGNORECASE type for the definition of individual columns. So it is possible to have some columns case sensitive and some not, even in the same table.

Only an administrator may do this.

SET INITIAL SCHEMA [2]

Users may change their base default schema name with the comand

SET INITIAL SCHEMA <schemaname>;
This is the schema which database object names will resolve to for the current user, unless overridden as explained in Schema object naming. For reasons of backwards compatibility, the initial schema value will not be persisted across database shutdowns until HSQLDB version 1.8.1. (I.e., INITIAL SCHEMA settings will be lost upon database shutdown with HSQLDB versions lower than version 1.8.1).

SET LOGSIZE

SET LOGSIZE <size>;

Sets the maximum size in MB of the .log file. Default is 200 MB. The database will be closed and opened (just like using CHECKPOINT) if the .log file gets over this limit, and so the .log file will shrink. 0 means no limit.

See also: CHECKPOINT.

SET MAXROWS

SET MAXROWS <maxwors>;

Describe me!

SET PASSWORD

SET PASSWORD <password>;

Changes the password of the currently connected user. Password must be double quotedEmpty password can be set using "".

SET PROPERTY[2]

SET PROPERTY <double quoted name> <value>;

Sets a database property. Properties that can be set using this command are either boolean or integral and are listed in the Advanced Topics chapter.

SET READONLY

SET READONLY {TRUE|FALSE};

Describe me!

SET REFERENTIAL INTEGRITY

SET REFERENTIAL_INTEGRITY { TRUE | FALSE };

This commands enables / disables the referential integrity checking (foreign keys). Normally it should be switched on (this is the default) but when importing data (and the data is imported in the 'wrong' order) the checking can be switched off.

Warning

Note that when referential integrity is switched back on, no check is made that the changes to the data are consistent with the existing referential integrity constraints. You can verify consistency using SQL queries and take appropriate actions.

Only an administrator may do this.

See also: CREATE TABLE.

SET SCHEMA[2]

SET SCHEMA <schemaname>;

Sets the current JDBC session's schema. The sole purpose for the session schema is to provide a default schema name for schema objects that do not have the schema name specified explicitly in the SQL command, or by association with another object of known schema. For example, if you run SELECT * FROM atbl;, HSQLDB will look for the table or view named atbl in the session's current schema.

Session schemas last only for the duration of the current session. When a new JDBC session is obtained, the new session will have the default schema.

SET SCRIPTFORMAT[2]

SET SCRIPTFORMAT {TEXT | BINARY | COMPRESSED};

Changes the format of the script file. BINARY and COMPRESSED formats are slightly faster and more compact than the default TEXT. Recommended only for very large script files.

SET TABLE INDEX

SET TABLE tableName INDEX 'index1rootPos index2rootPos ... ';

This command is only used internally to store the position of index roots in the .data file. It appears only in database script files; it should not be used directly.

SET TABLE READONLY[2]

SET TABLE <tablename> READONLY {TRUE | FALSE};

Sets the table as read only.

SET TABLE SOURCE[2]

SET TABLE <tablename> SOURCE <file and options> [DESC];

For details see the Text Tables chapter.

This command is used exclusively with TEXT tables to specify which file is used for storage of the data. The optional DESC qualifier results in the text file indexed from the end and opened as readonly. The <file and options> argument is a double quoted string that consists of:

    <file and options>::= <doublequote> <filepath>
        [<semicolon> <option>...] <doublequote>

Example:

    SET TABLE mytable SOURCE "myfile;fs=|;vs=.;lvs=~"

Supported Properties

quoted = { true | false }

default is true. If false, treats double quotes as normal characters

all_quoted = { true | false }

default is false. If true, adds double quotes around all fields.

encoding = <encoding name>

character encoding for text and character fields, for example, encoding=UTF-8

ignore_first = { true | false }

default is false. If true ignores the first line of the file

cache_scale= <numeric value>

exponent to calculate rows of the text file in cache. Default is 8, equivalent to nearly 800 rows

cache_size_scale = <numeric value>r

exponent to calculate average size of each row in cache. Default is 8, equivalent to 256 bytes per row.

fs = <unquoted character>

field separator

vs = <unquoted character>

varchar separator

lvs = <unquoted character>

long varchar separator

Special indicators for Hsqldb Text Table separators

\semi

semicolon

\quote

quote

\space

space character

\apos

apostrophe

\n

newline - Used as an end anchor (like $ in regular expressions)

\r

carriage return

\t

tab

\\

backslash

\u####

a Unicode character specified in hexadecimal

Only an administrator may do this.

SET WRITE DELAY[2]

SET WRITE_DELAY {{ TRUE | FALSE } | <seconds> | <milliseconds> MILLIS};

This 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 20 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. In practice, a write delay of 100 milliseconds provides better than 99.9999% reliability with an average one system crash per day, or 99.99999% with an average one system crash per 6 days.

Each time a SET WRITE_DELAY is issued with any value, a sync is immediately performed.

Only an administrator may do this.

SHUTDOWN

SHUTDOWN [IMMEDIATELY | COMPACT | SCRIPT[2]];

Closes the current database.

Varieties of the SHUTDOWN command

SHUTDOWN

Performs a checkpoint to creates a new .script file that has the minimum size and contains the data for memory tables only. It then backs up the .data file containing the CACHED TABLE data in zipped format to the .backup file and closes the database.

SHUTDOWN IMMEDIATELY

Just closes the database files (like when the Java process for the database is terminated); this command is used in tests of the recovery mechanism. This command should not be used as the routine method of closing the database.

SHUTDOWN COMPACT

Writes out a new .script file which contains the data for all the tables, including CACHED and TEXT tables. It then deletes the existing text table files and the .data file before rewriting them. After this, it backs up the .data file in the same way as normal SHUTDOWN. This operation shrinks all files to the minimum size.

SHUTDOWN SCRIPT

Similar to SHUTDOWN COMPACT but after writing the script and deleting the existing files, it does not rewrite the .data and text table files. After SHUTDOWN SCRIPT, only the .script and .properties file remain. At the next startup, these files are processed and the .data and .backup files are created. This command in effect performs part of the job of SHUTDOWN COMPACT, leaving the other part to be performed automatically at the next startup.

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

Only an administrator may use the SHUTDOWN command.

UPDATE

UPDATE table SET column = Expression [, ...] [WHERE Expression];

Modifies data of a table in the database.

See also: SELECT[2], INSERT, DELETE.

Schema object naming

Schema objects are database objects that are always scoped to a specific schema. Each schema has a namespace. There may be multiple schema objects of the same name, each in the namespace of a different schema. A particular schema object may nearly always be uniquely identified using the notation schemaname.objectname. All HSQLDB database objects are schema objects, other than the following.

Users

Roles

Store Procedure Java Classes

HSQL Aliases

Our current Java-class-based Triggers are not fully schema objects. However, we are in the process of implementing SQL-conformant triggers which will encompass our Java-class-based triggers. When this work is completed, HSQLDB triggers will be schema objects.

Sequences are schema objects with creation and removal permission governed by schema authorization (as described hereafter), but GRANT and REVOKE command do not work yet for sequences. In a future version of HSQLDB, sequence GRANTs and REVOKEs will work similarly to the current GRANT and REVOKE commands for table access.

Most of the time, you do not need to specify the schema for the desired schema object, because the implicit schema is usually the only one that can be used. For example, when creating an index, the target schema will default to that of the table which is the target of the index. Named constraints are an extreme example of this. There is never a need to specify a schema name for a constraint, since constraint names are only specified in a CREATE or ALTER TABLE command, and the schema must be that of the target table. If the implicit schema is not determined by a related object, then the default comes from your JDBC session's current schema setting. The session schema value will be your login user's initial schema, or whatever you last set it to with SET SCHEMA[2] in your current JDBC session with the SET SCHEMA command. (Your initial schema is "PUBLIC" unless changed with the ALTER USER SET INITIAL SCHEMA or the SET INITIAL SCHEMA [2] command).

In addition to namespace scoping, there are permission aspects to the schema of a database object. The authorization of a schema is a role or user that is basically the owner of the schema. Only a user with the DBA role (an admin user) or the owner of a schema may create objects, or modify the DDL of objects, in the namespace of that schema. In this way, a schema authorization is said to "own" the objects of that schema. A schema authorization/owner can be a role or a user (even a role with no members). The two schemas automatically created when a database is initialized are both owned by the role DBA.

An important implication to database objects being owned by the schema owner is, if a non-DBA database user is to have permission to create any database object, they must have ownership of a schema. To allow a user to create (or modify DDL of) objects in their own personal schema, you would create a new schema with that user as the authorization. To allow a non-DBA user to share create and DDL privileges in some schema, you would create this schema with a role as the authorization, then GRANT this role to all of the desired users.

The INFORMATION_SCHEMA is a system defined schema that contains the system tables for the database. This schema is read-only. When a database is created, a shema named PUBLIC is automatically created as the default schma. This schema has the authorization DBA. You can change the name of this schema. If all non-system schemas are dropped from a database, an empty PUBLIC schema is created again. So each database always has at least one non-system schema.

Data Types

Table 9.1. Data Types. The types on the same line are equivalent.

NameRangeJava Type
INTEGER | INTas Java typeint | java.lang.Integer
DOUBLE [PRECISION] | FLOATas Java typedouble | java.lang.Double
VARCHARas Integer.MAXVALUEjava.lang.String
VARCHAR_IGNORECASEas Integer.MAXVALUEjava.lang.String
CHAR | CHARACTERas Integer.MAXVALUEjava.lang.String
LONGVARCHARas Integer.MAXVALUEjava.lang.String
DATEas Java typejava.sql.Date
TIMEas Java typejava.sql.Time
TIMESTAMP | DATETIMEas Java typejava.sql.Timestamp
DECIMALNo limitjava.math.BigDecimal
NUMERICNo limitjava.math.BigDecimal
BOOLEAN | BITas Java typeboolean | java.lang.Boolean
TINYINTas Java typebyte | java.lang.Byte
SMALLINTas Java typeshort | java.lang.Short
BIGINTas Java typelong | java.lang.Long
REALas Java typedouble | java.lang.Double[2]
BINARYas Integer.MAXVALUEbyte[]
VARBINARYas Integer.MAXVALUEbyte[]
LONGVARBINARYas Integer.MAXVALUEbyte[]
OTHER | OBJECTas Integer.MAXVALUEjava.lang.Object

The uppercase names are the data types names defined by the SQL standard or commonly used by RDMS's. The data types in quotes are the Java class names - if these type names are used then they must be enclosed in quotes because in Java names are case-sensitive. Range indicates the maximum size of the object that can be stored. Where Integer.MAXVALUE is stated, this is a theoretical limit and in practice the maximum size of a VARCHAR or BINARY object that can be stored is dictated by the amount of memory available. In practice, objects of up to a megabyte in size have been successfully used in production databases.

The recommended Java mapping for the JDBC datatype FLOAT is as a Java type "double". Because of the potential confusion it is recommended that DOUBLE is used instead of FLOAT.

VARCHAR_IGNORECASE is a special case-insensitive type of VARCHAR. This type is not portable.

In table definition statements, HSQLDB accepts size, precision and scale qualifiers only for certain types: CHAR(s), VARCHAR(s), DOUBLE(p), NUMERIC(p), DECIMAL(p,s) and TIMESTAMP(p).

TIMESTAMP(p) can take only 0 or 6 as precision. Zero indicates no subsecond part. Without the precision, the default is 6.

By default specified precision and scale for the column is simply ignored by the engine. Instead, the values for the corresponding Java types are always used, which in the case of DECIMAL is an unlimited precision and scale. If a size is specified, it is stored in the database definition but is not enforeced by default. Once you have created the database (before adding data), you can add a database property value to enforce the sizes:

    SET PROPERTY "sql.enforce_strict_size" true

This will enforce the specified size and pad CHAR fields with spaces to fill the size. This complies with SQL standards by throwing an exception if an attempt is made to insert a string longer than the maximum size. It also results in all DECIMAL values conforming to the specified precision and scale.

CHAR and VARCHAR and LONGVARCHAR columns are by default compared and sorted according to POSIX standards. See the SET DATABASE COLLATION[2] section above to modify this behavior. The property sql.compare_in_locale is no longer supported. Instead, you can define a collation to be used for all character comparisons.

Columns of the type OTHER or OBJECT contain the serialized form of a Java Object in binary format. To insert or update such columns, a binary format string (see below under Expression) should be used. Using PreparedStatements with JDBC automates this transformation.

SQL Comments

-- SQL style line comment
// Java style line comment
/* C style line comment */

All these types of comments are ignored by the database.

Stored Procedures / Functions

Stored procedures are static Java functions that are called directly from the SQL language or using an alias. Calling Java functions (directly or using the alias) requires that the Java class can be reached by the database (server). The syntax is:

    "java.lang.Math.sqrt"(2.0)

This means the package must be provided, and the name must be written as one word, and inside " because otherwise it is converted to uppercase (and not found).

An alias can be created using the command CREATE ALIAS:

    CREATE ALIAS SQRT FOR "java.lang.Math.sqrt";

When an alias is defined, then the function can be called additionally using this alias:

    SELECT SQRT(A) , B FROM MYTABLE;

Only static java methods can be used as stored procedures. If, within the same class, there are overloaded methods with the same number of arguments, then the first one encountered by the program will be used. If you want to use Java library methods, it is recommended that you create your own class with static methods that act as wrappers around the Java library methods. This will allow you to control which method signature is used to call each Java library method.

Built-in Functions and Stored Procedures

Numerical built-in Functions / Stored Procedures

ABS(d)

returns the absolute value of a double value

ACOS(d)

returns the arc cosine of an angle

ASIN(d)

returns the arc sine of an angle

ATAN(d)

returns the arc tangent of an angle

ATAN2(a,b)

returns the tangent of a/b

BITAND(a,b)

return a & b

BITOR(a,b)

returns a | b

CEILING(d)

returns the smallest integer that is not less than d

COS(d)

returns the cosine of an angle

COT(d)

returns the cotangent of an angle

DEGREES(d)

converts radians to degrees

EXP(d)

returns e (2.718...) raised to the power of d

FLOOR(d)

returns the largest integer that is not greater than d

LOG(d)

returns the natural logarithm (base e)

LOG10(d)

returns the logarithm (base 10)

MOD(a,b)

returns a modulo b

PI()

returns pi (3.1415...)

POWER(a,b)

returns a raised to the power of b

RADIANS(d)

converts degrees to radians

RAND()

returns a random number x bigger or equal to 0.0 and smaller than 1.0

ROUND(a,b)

rounds a to b digits after the decimal point

ROUNDMAGIC(d)

solves rounding problems such as 3.11-3.1-0.01

SIGN(d)

returns -1 if d is smaller than 0, 0 if d==0 and 1 if d is bigger than 0

SIN(d)

returns the sine of an angle

SQRT(d)

returns the square root

TAN(A)

returns the trigonometric tangent of an angle

TRUNCATE(a,b)

truncates a to b digits after the decimal point

String built-in Functions / Stored Procedures

ASCII(s)

returns the ASCII code of the leftmost character of s

BIT_LENGTH(str)[2]

returns the length of the string in bits

CHAR(c)

returns a character that has the ASCII code c

CHAR_LENGTH(str)[2]

returns the length of the string in characters

CONCAT(str1,str2)

returns str1 + str2

DIFFERENCE(s1,s2)

returns the difference between the sound of s1 and s2

HEXTORAW(s1)[2]

returns translated string

INSERT(s,start,len,s2)

returns a string where len number of characters beginning at start has been replaced by s2

LCASE(s)

converts s to lower case

LEFT(s,count)

returns the leftmost count of characters of s) - requires double quoting - use SUBSTRING() instead

LENGTH(s)

returns the number of characters in s

LOCATE(search,s,[start])

returns the first index (1=left, 0=not found) where search is found in s, starting at start

LTRIM(s)

removes all leading blanks in s

OCTET_LENGTH(str)[2]

returns the length of the string in bytes (twice the number of characters)

RAWTOHEX(s1)[2]

returns translated string

REPEAT(s,count)

returns s repeated count times

REPLACE(s,replace,s2)

replaces all occurrences of replace in s with s2

RIGHT(s,count)

returns the rightmost count of characters of s

RTRIM(s)

removes all trailing spaces

SOUNDEX(s)

returns a four character code representing the sound of s

SPACE(count)

returns a string consisting of count spaces

SUBSTR(s,start[,len])

alias for substring

SUBSTRING(s,start[,len])

returns the substring starting at start (1=left) with length len

UCASE(s)

converts s to upper case

LOWER(s)

converts s to lower case

UPPER(s)

converts s to upper case

Date/Time built-in Functions / Stored Procedures

CURDATE()

returns the current date

CURTIME()

returns the current time

DATEDIFF(string, datetime1, datetime2)[2]

returns the count of units of time elapsed from datetime1 to datetime2. The string indicates the unit of time and can have the following values 'ms'='millisecond', 'ss'='second','mi'='minute','hh'='hour', 'dd'='day', 'mm'='month', 'yy' = 'year'. Both the long and short form of the strings can be used.

DAYNAME(date)

returns the name of the day

DAYOFMONTH(date)

returns the day of the month (1-31)

DAYOFWEEK(date)

returns the day of the week (1 means Sunday)

DAYOFYEAR(date)

returns the day of the year (1-366)

HOUR(time)

return the hour (0-23)

MINUTE(time)

returns the minute (0-59)

MONTH(date)

returns the month (1-12)

MONTHNAME(date)

returns the name of the month

NOW()

returns the current date and time as a timestamp) - use CURRENT_TIMESTAMP instead

QUARTER(date)

returns the quarter (1-4)

SECOND(time)

returns the second (0-59)

WEEK(date)

returns the week of this year (1-53)

YEAR(date)

returns the year

CURRENT_DATE[2]

returns the current date

CURRENT_TIME[2]

returns the current time

CURRENT_TIMESTAMP[2]

returns the current timestamp

System/Connection built-in Functions / Stored Procedures

DATABASE()

returns the name of the database of this connection

USER()

returns the user name of this connection

CURRENT_USER

SQL standard function, returns the user name of this connection

IDENTITY()

returns the last identity values that was inserted by this connection

System built-in Functions / Stored Procedures

IFNULL(exp,value)

if exp is null, value is returned else exp) - use COALESCE() instead

CASEWHEN(exp,v1,v2)

if exp is true, v1 is returned, else v2) - use CASE WHEN instead

CONVERT(term,type)

converts exp to another data type

CAST(term AS type)[2]

converts exp to another data type

COALESCE(expr1,expr2,expr3,...)[2]

if expr1 is not null then it is returned else, expr2 is evaluated and if not null it is returned and so on

NULLIF(v1,v2)[2]

if v1 equals v2 return null, otherwise v1

CASE v1 WHEN...[2]

CASE v1 WHEN v2 THEN v3 [ELSE v4] END

when v1 equals v2 return v3 [otherwise v4 or null if there is no ELSE]

CASE WHEN...[2]

CASE WHEN expr1 THEN v1[WHEN expr2 THEN v2] [ELSE v4] END

when expr1 is true return v1 [optionally repeated for more cases] [otherwise v4 or null if there is no ELSE]

EXTRACT[2]

EXTRACT ({YEAR | MONTH | DAY | HOUR | MINUTE | SECOND} FROM <datetime value>)

POSITION (... IN ..)[2]

POSITION(<string expression> IN <string expression>)

if the first string is a sub-string of the second one, returns the position of the sub-string, counting from one; otherwise 0

SUBSTRING(... FROM ... FOR ...)[2]

SUBSTRING(<string expression> FROM <numeric expression> [FOR <numeric expression>])

TRIM( LEDING ... FROM ...)[2]

TRIM([{LEADING | TRAILING | BOTH}] FROM <string expression>)

See also: CALL, CREATE ALIAS.

SQL Expression

[NOT] condition [{ OR | AND } condition]

Components of SQL Expressions

condition
   { value [|| value]
  | value { = | < | <= | > | >= | <> | != } value
  | value IS [NOT] NULL
  | EXISTS(selectStatement)
  | value BETWEEN value AND value
  | value [NOT] IN ( {value [, ...] | selectStatement } )
  | value [NOT] LIKE value [ESCAPE] value }
value
   [+ | -] { term [{ + | - | * | / | || } term]
  | ( condition )
  | function ( [parameter] [,...] )
  | selectStatement giving one value
  | {ANY|ALL} (selectStatement giving single column)
term
   { 'string' | number | floatingpoint
  | [table.]column | TRUE | FALSE | NULL }
sequence
   NEXT VALUE FOR <sequence>

HSQLDB does not currently enforce the SQL 200n proposed rules on where sequence generated values are allowed to be used. In general, these values can be used in insert and update statements but not in CASE statements, order by clauses, search conditions, aggregate functions, or grouped queries.

string

Strings in HSQLDB are Unicode strings. A string starts and ends with a single ' (singlequote). In a string started with ' (singlequote) use '' (two singlequotes) to create a ' (singlequote).

String contatenation should be performed with the standard SQL operator || rather than the non-standard + operator.

The LIKE keyword uses '%' to match any (including 0) number of characters, and '_' to match exactly one character. To search for '%' or '_' itself an escape character must also be specified using the ESCAPE clause. For example, if the backslash is the escaping character, '\%' and '\_' can be used to find the '%' and '_' characters themselves. For example, SELECT .... LIKE '\_%' ESCAPE '\' will find the strings beginning with an underscore.

name

The character set for quoted identifiers (names) in HSQLDB is Unicode.

A unquoted identifier (name) starts with a letter and is followed by any number of ASCII letters or digits. When an SQL statement is issued, any lowercase characters in unquoted identifiers are converted to uppercase. Because of this, unquoted names are in fact ALL UPPERCASE when used in SQL statements. An important implication of this is the for accessing columns names via JDBC DatabaseMetaData: the internal form, which is the ALL UPPERCASE must be used if the column name was not quoted in the CREATE TABLE statement.

Quoted identifiers can be used as names (for tables, columns, constraints or indexes). Quoted identifiers start and end with " (one doublequote). A quoted identifier can contain any Unicode character, including space. In a quoted identifier use "" (two doublequotes) to create a " (one doublequote). With quoted identifiers it is possible to create mixed-case table and column names. Example:

    CREATE TABLE "Address" ("Nr" INTEGER,"Name" VARCHAR);
    SELECT "Nr", "Name" FROM "Address";

The equivalent quoted identifier can be used for an unquoted identifer by converting the identifier to all uppercase and quoting it. For example, if a table name is defined as Address2 (unquoted), it can be referred to by its quoted form, "ADDRESS2", as well as address2, aDDress2 and ADDRESS2. Quoted identifiers should not be confused with SQL strings.

Quoting can sometimes be used for identifiers, aliases or functions when there is an ambiguity. For example:

    SELECT COUNT(*) "COUNT" FROM MYTABLE;
    SELECT "LEFT"(COL1, 2) FROM MYTABLE;

Although HSQLDB 1.8.0 does not force unquoted identifiers to contain only ASCII characters, the use of non-ASCII characters in these identifiers does not comply with SQL standards. Portability between different JRE locales could be an issue when accented characters (or extended unicode characters) are used in unquoted identifiers. Because native Java methods are used to convert the identifier to uppercase, the result may vary not be expected in different locales. It is recommended that accented characters are used only in quoted identifiers.

When using JDBC DatabaseMetaData methods that take table, column, or index identifiers as arguments, treat the names as they are registered in the database. With these methods, unquoted identifiers should be used in all-uppercase to get the correct result. Quoted identifiers should be used in the exact case combination as they were defined - no quote character should be included around the name. JDBC methods that return a result set containing such identifiers return unquoted identifiers as all-uppercase and quoted identifiers in the exact case they are registered in the database (a change from 1.6.1 and previous versions).

Please also note that the JDBC getXXX(String columnName) methods interpret the columnName as case-independent. This is a general feature of JDBC and not specific to HSQLDB.

password

Passwords must be double quoted and used consistently. Passwords are case insensitive only for backward compatibility. This may change in future versions.

values
  • A DATE literal starts and ends with ' (singlequote), the format is yyyy-mm-dd (see java.sql.Date.

  • A TIME liteal starts and ends with ' (singlequote), the format is hh:mm:ss (see java.sql.Time).

  • A TIMESTAMP or DATETIME literal starts and ends with ' (singlequote), the format is yyyy-mm-dd hh:mm:ss.SSSSSSSSS (see java.sql.Timestamp).

When specifying default values for date / time columns in CREATE TABLE statements, or in SELECT,INSERT, and UPDATE statements, special SQL functions: NOW, SYSDATE, TODAY, CURRENT_TIMESTAMP, CURRENT_TIME and CURRENT_DATE (case independent) can be used. NOW is used for TIME and TIMESTAMP columns, TODAY is used for DATE columns. The data and time variants CURRENT_* are SQL standard versions and should be used in preference to others. Example:

    CREATE TABLE T(D DATE DEFAULT CURRENT_DATE);
    CREATE TABLE T1(TS TIMESTAMP DEFAULT CURRENT_TIMESTAMP);

Binary data starts and ends with ' (singlequote), the format is hexadecimal. '0004ff' for example is 3 bytes, first 0, second 4 and last 255 (0xff).

Any number of commands may be combined. With combined commands, ';' (semicolon) must be used at the end of each command to ensure data integrity, despite the fact that the engine may understand the end of commands and not return an error when a semicolon is not used.



[2] These features were added by HSQL Development Group since April 2001