SQL Grammar
Index
Commands (Data Manipulation)
SELECT INSERT UPDATE DELETE |
BACKUP CALL EXPLAIN MERGE |
RUNSCRIPT SCRIPT SHOW |
Commands (Data Definition)
Commands (Other)
Other Grammar
System Tables
Information Schema
Range Table
Details
Click on the header to switch between railroad diagram and BNF.
SELECT
SELECT |
|
| selectExpression |
|
FROM tableExpression |
|
|
|
|
|
|
|
|
Selects data from a table or multiple tables. GROUP BY
groups the the result by the given expression(s). HAVING
filter rows after grouping. ORDER BY
sorts the result by the given column(s) or expression(s). UNION
combines the result of this query with the results of another query.
LIMIT
limits the number of rows returned by the query (no limit if null or smaller than zero). OFFSET
specified how many rows to skip. SAMPLE_SIZE
limits the number of rows read for aggregate queries.
Multiple set operators (UNION, INTERSECT, MINUS, EXPECT
) are evaluated from left to right. For compatibility with other databases and future versions of H2 please use parentheses.
If FOR UPDATE
is specified, the tables are locked for writing. When using MVCC
, only the selected rows are locked as in an UPDATE
statement. In this case, aggregate, GROUP BY, DISTINCT
queries or joins are not allowed in this case.
Example:
SELECT * FROM TEST;
SELECT * FROM TEST ORDER BY NAME;
SELECT ID, COUNT(*) FROM TEST GROUP BY ID;
SELECT NAME, COUNT(*) FROM TEST GROUP BY NAME HAVING COUNT(*) > 2;
SELECT 'ID' COL, MAX(ID) AS MAX FROM TEST UNION SELECT 'NAME', MAX(NAME) FROM TEST;
SELECT * FROM TEST LIMIT 1000;
SELECT * FROM (SELECT ID, COUNT(*) FROM TEST
GROUP BY ID UNION SELECT NULL, COUNT(*) FROM TEST)
ORDER BY 1 NULLS LAST;
INSERT
INSERT INTO tableName |
| |||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||
|
Inserts a new row / new rows into a table.
When using DIRECT
, then the results from the query are directly applied in the target table without any intermediate step.
When using SORTED
, b-tree pages are split at the insertion point. This can improve performance and reduce disk usage.
Example:
INSERT INTO TEST VALUES(1, 'Hello')
UPDATE
UPDATE tableName |
| SET |
| |||||||||||||||||
|
|
|
Updates data in a table.
Example:
UPDATE TEST SET NAME='Hi' WHERE ID=1;
UPDATE PERSON P SET NAME=(SELECT A.NAME FROM ADDRESS A WHERE A.ID=P.ID);
DELETE
DELETE |
| FROM tableName |
|
|
Deletes rows form a table. If TOP
or LIMIT
is specified, at most the specified number of rows are deleted (no limit if null or smaller than zero).
Example:
DELETE FROM TEST WHERE ID=2
BACKUP
BACKUP TO fileNameString |
Backs up the database files to a .zip file. Objects are not locked, but the backup is transactionally consistent because the transaction log is also copied. Admin rights are required to execute this command.
Example:
BACKUP TO 'backup.zip'
CALL
CALL expression |
Calculates a simple expression. This statement returns a result set with one row, except if the called function returns a result set itself. If the called function returns an array, then each element in this array is returned as a column.
Example:
CALL 15*25
EXPLAIN
Shows the execution plan for a statement. When using EXPLAIN ANALYZE
, the statement is actually executed, and the query plan will include the actual row scan count for each table.
Example:
EXPLAIN SELECT * FROM TEST WHERE ID=1
MERGE
MERGE INTO tableName |
|
|
| |||||||||||||||||||||||||
select |
Updates existing rows, and insert rows that don't exist. If no key column is specified, the primary key columns are used to find the row. If more than one row per new row is affected, an exception is thrown. If the table contains an auto-incremented key or identity column, and the row was updated, the generated key is set to 0; otherwise it is set to the new key.
Example:
MERGE INTO TEST KEY(ID) VALUES(2, 'World')
RUNSCRIPT
Runs a SQL script from a file. The script is a text file containing SQL statements; each statement must end with ';'. This command can be used to restore a database from a backup. The password must be in single quotes; it is case sensitive and can contain spaces.
Instead of a file name, an URL may be used. To read a stream from the classpath, use the prefix 'classpath:'. See the Pluggable File System section on the Advanced page.
The compression algorithm must match the one used when creating the script. Instead of a file, an URL may be used.
Admin rights are required to execute this command.
Example:
RUNSCRIPT FROM 'backup.sql'
RUNSCRIPT FROM 'classpath:/com/acme/test.sql'
SCRIPT
SCRIPT |
|
|
|
|
|
|
|
|
|
Creates a SQL script from the database.
SIMPLE
does not use multi-row insert statements. NODATA
will not emit INSERT
statements. If the DROP
option is specified, drop statements are created for tables, views, and sequences. If the block size is set, CLOB
and BLOB
values larger than this size are split into separate blocks. BLOCKSIZE
is used when writing out LOB
data, and specifies the point at the values transition from being inserted as inline values, to be inserted using out-of-line commands. NOSETTINGS
turns off dumping the database settings (the SET XXX
commands)
If no file name is specified, the script is returned as a result set. This command can be used to create a backup of the database. For long term storage, it is more portable than copying the database files.
If a file name is specified, then the whole script (including insert statements) is written to this file, and a result set without the insert statements is returned.
The password must be in single quotes; it is case sensitive and can contain spaces.
This command locks objects while it is running. Admin rights are required to execute this command.
When using the TABLE
or SCHEMA
option, only the selected table(s) / schema(s) are included.
Example:
SCRIPT NODATA
SHOW
SHOW |
|
Lists the schemas, tables, or the columns of a table.
Example:
SHOW TABLES
ALTER INDEX RENAME
ALTER INDEX indexName RENAME TO newIndexName |
Renames an index. This command commits an open transaction.
Example:
ALTER INDEX IDXNAME RENAME TO IDX_TEST_NAME
ALTER SCHEMA RENAME
ALTER SCHEMA schema RENAME TO newSchemaName |
Renames a schema. This command commits an open transaction.
Example:
ALTER SCHEMA TEST RENAME TO PRODUCTION
ALTER SEQUENCE
ALTER SEQUENCE sequenceName |
|
|
|
|
|
|
Changes the parameters of a sequence. This command does not commit the current transaction; however the new value is used by other transactions immediately, and rolling back this command has no effect.
Example:
ALTER SEQUENCE SEQ_ID RESTART WITH 1000
ALTER TABLE ADD
ALTER TABLE tableName ADD |
|
| ||||||||||||||||||||||||||
|
Adds a new column to a table. This command commits an open transaction.
Example:
ALTER TABLE TEST ADD CREATEDATE TIMESTAMP
ALTER TABLE ADD CONSTRAINT
ALTER TABLE tableName ADD constraint |
|
Adds a constraint to a table. If NOCHECK
is specified, existing rows are not checked for consistency (the default is to check consistency for existing rows). The required indexes are automatically created if they don't exist yet. It is not possible to disable checking for unique constraints. This command commits an open transaction.
Example:
ALTER TABLE TEST ADD CONSTRAINT NAME_UNIQUE UNIQUE(NAME)
ALTER TABLE ALTER COLUMN
ALTER TABLE tableName ALTER COLUMN columnName |
| |||||||||||||||||||||||||||||||||||||||
| |||||||||||||||||||||||||||||||||||||||
| |||||||||||||||||||||||||||||||||||||||
| |||||||||||||||||||||||||||||||||||||||
| |||||||||||||||||||||||||||||||||||||||
| |||||||||||||||||||||||||||||||||||||||
|
Changes the data type of a column, rename a column, change the identity value, or change the selectivity.
Changing the data type fails if the data can not be converted.
RESTART
changes the next value of an auto increment column. The column must already be an auto increment column. For RESTART
, the same transactional rules as for ALTER SEQUENCE
apply.
SELECTIVITY
sets the selectivity (1-100) for a column. Setting the selectivity to 0 means the default value. Selectivity is used by the cost based optimizer to calculate the estimated cost of an index. Selectivity 100 means values are unique, 10 means every distinct value appears 10 times on average.
SET DEFAULT
changes the default value of a column.
SET NULL
sets a column to allow NULL
. The row may not be part of a primary key. Single column indexes on this column are dropped.
SET NOT NULL
sets a column to not allow NULL
. Rows may not contains NULL
in this column.
This command commits an open transaction.
Example:
ALTER TABLE TEST ALTER COLUMN NAME CLOB;
ALTER TABLE TEST ALTER COLUMN NAME RENAME TO TEXT;
ALTER TABLE TEST ALTER COLUMN ID RESTART WITH 10000;
ALTER TABLE TEST ALTER COLUMN NAME SELECTIVITY 100;
ALTER TABLE TEST ALTER COLUMN NAME SET DEFAULT '';
ALTER TABLE TEST ALTER COLUMN NAME SET NOT NULL;
ALTER TABLE TEST ALTER COLUMN NAME SET NULL;
ALTER TABLE DROP COLUMN
ALTER TABLE tableName DROP COLUMN |
| columnName |
Removes a column from a table. This command commits an open transaction.
Example:
ALTER TABLE TEST DROP COLUMN NAME
ALTER TABLE DROP CONSTRAINT
ALTER TABLE tableName DROP |
|
Removes a constraint or a primary key from a table. This command commits an open transaction.
Example:
ALTER TABLE TEST DROP CONSTRAINT UNIQUE_NAME
ALTER TABLE SET
ALTER TABLE tableName SET REFERENTIAL_INTEGRITY |
|
Disables or enables referential integrity checking for a table. This command can be used inside a transaction. Enabling referential integrity does not check existing data, except if CHECK
is specified. Use SET REFERENTIAL_INTEGRITY
to disable it for all tables; the global flag and the flag for each table are independent.
This command commits an open transaction.
Example:
ALTER TABLE TEST SET REFERENTIAL_INTEGRITY FALSE
ALTER TABLE RENAME
Renames a table. This command commits an open transaction.
Example:
ALTER TABLE TEST RENAME TO MY_DATA
ALTER USER ADMIN
ALTER USER userName ADMIN |
|
Switches the admin flag of a user on or off.
Only unquoted or uppercase user names are allowed. Admin rights are required to execute this command. This command commits an open transaction.
Example:
ALTER USER TOM ADMIN TRUE
ALTER USER RENAME
ALTER USER userName RENAME TO newUserName |
Renames a user. After renaming a user, the password becomes invalid and needs to be changed as well.
Only unquoted or uppercase user names are allowed. Admin rights are required to execute this command. This command commits an open transaction.
Example:
ALTER USER TOM RENAME TO THOMAS
ALTER USER SET PASSWORD
Changes the password of a user. Only unquoted or uppercase user names are allowed. The password must be enclosed in single quotes. It is case sensitive and can contain spaces. The salt and hash values are hex strings.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
ALTER USER SA SET PASSWORD 'rioyxlgt'
ALTER VIEW
ALTER VIEW viewName RECOMPILE |
Recompiles a view after the underlying tables have been changed or created. This command is used for views created using CREATE FORCE VIEW
. This command commits an open transaction.
Example:
ALTER VIEW ADDRESS_VIEW RECOMPILE
ANALYZE
ANALYZE |
|
Updates the selectivity statistics of all tables. The selectivity is used by the cost based optimizer to select the best index for a given query. If no sample size is set, up to 10000 rows per table are read. The value 0 means all rows are read. The selectivity can be set manually using ALTER TABLE ALTER COLUMN SELECTIVITY
. Manual values are overwritten by this statement. The selectivity is available in the INFORMATION_SCHEMA.COLUMNS
table.
This command commits an open transaction.
Example:
ANALYZE SAMPLE_SIZE 1000
COMMENT
COMMENT ON |
| ||||||||||||||||||||||||||||||||||||||||||||||||
|
IS expression |
Sets the comment of a database object. Use NULL
to remove the comment.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
COMMENT ON TABLE TEST IS 'Table used for testing'
CREATE AGGREGATE
CREATE AGGREGATE |
| newAggregateName FOR className |
Creates a new user-defined aggregate function. The method name must be the full qualified class name. The class must implement the interface org.h2.api.AggregateFunction
.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
CREATE AGGREGATE MEDIAN FOR "com.acme.db.Median"
CREATE ALIAS
CREATE ALIAS |
| newFunctionAliasName |
|
|
| |||
|
Creates a new function alias. If this is a ResultSet returning function, by default the return value is cached in a local temporary file.
NOBUFFER
- disables caching of ResultSet return value to temporary file.
DETERMINISTIC
- Deterministic functions must always return the same value for the same parameters.
The method name must be the full qualified class and method name, and may optionally include the parameter classes as in java.lang.Integer.parseInt(java.lang.String, int)
. The class and the method must both be public, and the method must be static. The class must be available in the classpath of the database engine (when using the server mode, it must be in the classpath of the server).
When defining a function alias with source code, the Sun javac
is compiler is used if the file tools.jar
is in the classpath. If not, javac
is run as a separate process. Only the source code is stored in the database; the class is compiled each time the database is re-opened. Source code is usually passed as dollar quoted text to avoid escaping problems. If import statements are used, then the tag @CODE
must be added before the method.
If the method throws an SQLException
, it is directly re-thrown to the calling application; all other exceptions are first converted to a SQLException
.
If the first parameter of the Java function is a java.sql.Connection
, then a connection to the database is provided. This connection must not be closed. If the class contains multiple methods with the given name but different parameter count, all methods are mapped.
Admin rights are required to execute this command. This command commits an open transaction.
If you have the Groovy jar in your classpath, it is also possible to write methods using Groovy.
Example:
CREATE ALIAS MY_SQRT FOR "java.lang.Math.sqrt";
CREATE ALIAS GET_SYSTEM_PROPERTY FOR "java.lang.System.getProperty";
CALL GET_SYSTEM_PROPERTY('java.class.path');
CALL GET_SYSTEM_PROPERTY('com.acme.test', 'true');
CREATE ALIAS REVERSE AS $$ String reverse(String s) { return new StringBuilder(s).reverse().toString(); } $$;
CALL REVERSE('Test');
CREATE ALIAS tr AS $$@groovy.transform.CompileStatic
static String tr(String str, String sourceSet, String replacementSet){
return str.tr(sourceSet, replacementSet);
}
$$
CREATE CONSTANT
CREATE CONSTANT |
| newConstantName VALUE expression |
Creates a new constant. This command commits an open transaction.
Example:
CREATE CONSTANT ONE VALUE 1
CREATE DOMAIN
CREATE DOMAIN |
| newDomainName AS dataType |
|
|
|
|
Creates a new data type (domain). The check condition must evaluate to true or to NULL
(to prevent NULL
, use NOT NULL
). In the condition, the term VALUE
refers to the value being tested.
Domains are usable within the whole database. They can not be created in a specific schema.
This command commits an open transaction.
Example:
CREATE DOMAIN EMAIL AS VARCHAR(255) CHECK (POSITION('@', VALUE) > 1)
CREATE INDEX
CREATE
| ||||||||||||||||||||||||||||||||||||||||
|
ON tableName ( indexColumn |
| ) |
Creates a new index. This command commits an open transaction.
Hash indexes are meant for in-memory databases and memory tables (CREATE MEMORY TABLE
). For other tables, or if the index contains multiple columns, the HASH
keyword is ignored. Hash indexes can only test for equality, and do not support range queries (similar to a hash table). Non-unique keys are supported. Spatial indexes are supported only on Geometry columns.
Example:
CREATE INDEX IDXNAME ON TEST(NAME)
CREATE LINKED TABLE
CREATE |
|
| LINKED TABLE |
|
name ( driverString , urlString , userString , passwordString , |
| originalTableString ) |
|
Creates a table link to an external table. The driver name may be empty if the driver is already loaded. If the schema name is not set, only one table with that name may exist in the target database.
FORCE
- Create the LINKED TABLE
even if the remote database/table does not exist.
EMIT UPDATES
- Usually, for update statements, the old rows are deleted first and then the new rows are inserted. It is possible to emit update statements (except on rollback), however in this case multi-row unique key updates may not always work. Linked tables to the same database share one connection.
READONLY
- is set, the remote table may not be updated. This is enforced by H2.
If the connection to the source database is lost, the connection is re-opened (this is a workaround for MySQL that disconnects after 8 hours of inactivity by default).
If a query is used instead of the original table name, the table is read only. Queries must be enclosed in parenthesis: (SELECT * FROM ORDERS)
.
To use JNDI
to get the connection, the driver class must be a javax.naming.Context (for example javax.naming.InitialContext
), and the URL must be the resource name (for example java:comp/env/jdbc/Test
).
Admin rights are required to execute this command. This command commits an open transaction.
Example:
CREATE LINKED TABLE LINK('org.h2.Driver', 'jdbc:h2:test2', 'sa', 'sa', 'TEST');
CREATE LINKED TABLE LINK('', 'jdbc:h2:test2', 'sa', 'sa',
'(SELECT * FROM TEST WHERE ID>0)');
CREATE LINKED TABLE LINK('javax.naming.InitialContext',
'java:comp/env/jdbc/Test', NULL, NULL, '(SELECT * FROM TEST WHERE ID>0)');
CREATE ROLE
CREATE ROLE |
| newRoleName |
Creates a new role. This command commits an open transaction.
Example:
CREATE ROLE READONLY
CREATE SCHEMA
CREATE SCHEMA |
| name |
|
Creates a new schema. If no owner is specified, the current user is used. The user that executes the command must have admin rights, as well as the owner. Specifying the owner currently has no effect.
This command commits an open transaction.
Example:
CREATE SCHEMA TEST_SCHEMA AUTHORIZATION SA
CREATE SEQUENCE
CREATE SEQUENCE |
| newSequenceName |
|
|
|
|
|
|
Creates a new sequence. The data type of a sequence is BIGINT
. Used values are never re-used, even when the transaction is rolled back.
The cache is the number of pre-allocated numbers. If the system crashes without closing the database, at most this many numbers are lost. The default cache size is 32. To disable caching, use the cache size 1 or lower.
This command commits an open transaction.
Example:
CREATE SEQUENCE SEQ_ID
CREATE TABLE
CREATE |
|
|
TABLE |
| name |
|
|
|
|
|
Creates a new table.
Cached tables (the default for regular tables) are persistent, and the number of rows is not limited by the main memory. Memory tables (the default for temporary tables) are persistent, but the index data is kept in main memory, that means memory tables should not get too large.
Temporary tables are deleted when closing or opening a database. Temporary tables can be global (accessible by all connections) or local (only accessible by the current connection). The default for temporary tables is global. Indexes of temporary tables are kept fully in main memory, unless the temporary table is created using CREATE CACHED TABLE
.
The ENGINE
option is only required when custom table implementations are used. The table engine class must implement the interface org.h2.api.TableEngine
. Any table engine parameters are passed down in the tableEngineParams field of the CreateTableData object.
Tables with the NOT PERSISTENT
modifier are kept fully in memory, and all rows are lost when the database is closed.
The column definition is optional if a query is specified. In that case the column list of the query is used.
This command commits an open transaction, except when using TRANSACTIONAL
(only supported for temporary tables).
Example:
CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255))
CREATE TRIGGER
CREATE TRIGGER |
| newTriggerName |
|
|
| ON tableName |
|
|
| CALL triggeredClassName |
Creates a new trigger. The trigger class must be public and implement org.h2.api.Trigger
. Inner classes are not supported. The class must be available in the classpath of the database engine (when using the server mode, it must be in the classpath of the server).
BEFORE
triggers are called after data conversion is made, default values are set, null and length constraint checks have been made; but before other constraints have been checked. If there are multiple triggers, the order in which they are called is undefined.
ROLLBACK
can be specified in combination with INSERT, UPDATE
, and DELETE
. Only row based AFTER
trigger can be called on ROLLBACK
. Exceptions that occur within such triggers are ignored. As the operations that occur within a trigger are part of the transaction, ROLLBACK
triggers are only required if an operation communicates outside of the database.
INSTEAD OF
triggers are implicitly row based and behave like BEFORE
triggers. Only the first such trigger is called. Such triggers on views are supported. They can be used to make views updatable.
A BEFORE SELECT
trigger is fired just before the database engine tries to read from the table. The trigger can be used to update a table on demand. The trigger is called with both 'old' and 'new' set to null.
The MERGE
statement will call both INSERT
and UPDATE
triggers. Not supported are SELECT
triggers with the option FOR EACH ROW
, and AFTER SELECT
triggers.
Committing or rolling back a transaction within a trigger is not allowed, except for SELECT
triggers.
By default a trigger is called once for each statement, without the old and new rows. FOR EACH ROW
triggers are called once for each inserted, updated, or deleted row.
QUEUE
is implemented for syntax compatibility with HSQL
and has no effect.
The trigger need to be created in the same schema as the table. The schema name does not need to be specified when creating the trigger.
This command commits an open transaction.
Example:
CREATE TRIGGER TRIG_INS BEFORE INSERT ON TEST FOR EACH ROW CALL "MyTrigger"
CREATE USER
Creates a new user. For compatibility, only unquoted or uppercase user names are allowed. The password must be in single quotes. It is case sensitive and can contain spaces. The salt and hash values are hex strings.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
CREATE USER GUEST PASSWORD 'abc'
CREATE VIEW
Creates a new view. If the force option is used, then the view is created even if the underlying table(s) don't exist.
If the OR REPLACE
clause is used an existing view will be replaced, and any dependent views will not need to be recreated. If dependent views will become invalid as a result of the change an error will be generated, but this error can be ignored if the FORCE
clause is also used.
Views are not updatable except when using 'instead of' triggers.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
CREATE VIEW TEST_VIEW AS SELECT * FROM TEST WHERE ID < 100
DROP AGGREGATE
DROP AGGREGATE |
| aggregateName |
Drops an existing user-defined aggregate function.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
DROP AGGREGATE MEDIAN
DROP ALIAS
DROP ALIAS |
| existingFunctionAliasName |
Drops an existing function alias.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
DROP ALIAS MY_SQRT
DROP ALL OBJECTS
DROP ALL OBJECTS |
|
Drops all existing views, tables, sequences, schemas, function aliases, roles, user-defined aggregate functions, domains, and users (except the current user). If DELETE FILES
is specified, the database files will be removed when the last user disconnects from the database. Warning: this command can not be rolled back.
Admin rights are required to execute this command.
Example:
DROP ALL OBJECTS
DROP CONSTANT
DROP CONSTANT |
| constantName |
Drops a constant. This command commits an open transaction.
Example:
DROP CONSTANT ONE
DROP DOMAIN
DROP DOMAIN |
| domainName |
Drops a data type (domain). This command commits an open transaction.
Example:
DROP DOMAIN EMAIL
DROP INDEX
DROP INDEX |
| indexName |
Drops an index. This command commits an open transaction.
Example:
DROP INDEX IF EXISTS IDXNAME
DROP ROLE
DROP ROLE |
| roleName |
Drops a role. This command commits an open transaction.
Example:
DROP ROLE READONLY
DROP SCHEMA
DROP SCHEMA |
| schemaName |
Drops a schema. This command commits an open transaction.
Example:
DROP SCHEMA TEST_SCHEMA
DROP SEQUENCE
DROP SEQUENCE |
| sequenceName |
Drops a sequence. This command commits an open transaction.
Example:
DROP SEQUENCE SEQ_ID
DROP TABLE
DROP TABLE |
| tableName |
|
|
Drops an existing table, or a list of tables. The command will fail if dependent views exist and the RESTRICT
clause is used (the default). All dependent views are dropped as well if the CASCADE
clause is used. This command commits an open transaction.
Example:
DROP TABLE TEST
DROP TRIGGER
DROP TRIGGER |
| triggerName |
Drops an existing trigger. This command commits an open transaction.
Example:
DROP TRIGGER TRIG_INS
DROP USER
DROP USER |
| userName |
Drops a user. The current user cannot be dropped. For compatibility, only unquoted or uppercase user names are allowed.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
DROP USER TOM
DROP VIEW
DROP VIEW |
| viewName |
|
Drops an existing view. All dependent views are dropped as well if the CASCADE
clause is used (the default). The command will fail if dependent views exist and the RESTRICT
clause is used. This command commits an open transaction.
Example:
DROP VIEW TEST_VIEW
TRUNCATE TABLE
TRUNCATE TABLE tableName |
Removes all rows from a table. Unlike DELETE FROM
without where clause, this command can not be rolled back. This command is faster than DELETE
without where clause. Only regular data tables without foreign key constraints can be truncated (except if referential integrity is disabled for this database or for this table). Linked tables can't be truncated.
This command commits an open transaction.
Example:
TRUNCATE TABLE TEST
CHECKPOINT
CHECKPOINT
Flushes the data to disk.
Admin rights are required to execute this command.
Example:
CHECKPOINT
CHECKPOINT SYNC
CHECKPOINT SYNC |
Flushes the data to disk and and forces all system buffers be written to the underlying device.
Admin rights are required to execute this command.
Example:
CHECKPOINT SYNC
COMMIT
COMMIT |
|
Commits a transaction.
Example:
COMMIT
COMMIT TRANSACTION
COMMIT TRANSACTION transactionName |
Sets the resolution of an in-doubt transaction to 'commit'.
Admin rights are required to execute this command. This command is part of the 2-phase-commit protocol.
Example:
COMMIT TRANSACTION XID_TEST
GRANT RIGHT
Grants rights for a table to a user or role.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
GRANT SELECT ON TEST TO READONLY
GRANT ALTER ANY SCHEMA
GRANT ALTER ANY SCHEMA TO userName |
Grant schema altering rights to a user.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
GRANT ALTER ANY SCHEMA TO Bob
GRANT ROLE
Grants a role to a user or role.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
GRANT READONLY TO PUBLIC
HELP
HELP |
|
Displays the help pages of SQL commands or keywords.
Example:
HELP SELECT
PREPARE COMMIT
PREPARE COMMIT newTransactionName |
Prepares committing a transaction. This command is part of the 2-phase-commit protocol.
Example:
PREPARE COMMIT XID_TEST
REVOKE RIGHT
Removes rights for a table from a user or role.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
REVOKE SELECT ON TEST FROM READONLY
REVOKE ROLE
Removes a role from a user or role.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
REVOKE READONLY FROM TOM
ROLLBACK
ROLLBACK |
|
Rolls back a transaction. If a savepoint name is used, the transaction is only rolled back to the specified savepoint.
Example:
ROLLBACK
ROLLBACK TRANSACTION
ROLLBACK TRANSACTION transactionName |
Sets the resolution of an in-doubt transaction to 'rollback'.
Admin rights are required to execute this command. This command is part of the 2-phase-commit protocol.
Example:
ROLLBACK TRANSACTION XID_TEST
SAVEPOINT
SAVEPOINT savepointName |
Create a new savepoint. See also ROLLBACK
. Savepoints are only valid until the transaction is committed or rolled back.
Example:
SAVEPOINT HALF_DONE
SET @
SET @variableName |
| expression |
Updates a user-defined variable. Variables are not persisted and session scoped, that means only visible from within the session in which they are defined. This command does not commit a transaction, and rollback does not affect it.
Example:
SET @TOTAL=0
SET ALLOW_LITERALS
SET ALLOW_LITERALS |
|
This setting can help solve the SQL injection problem. By default, text and number literals are allowed in SQL statements. However, this enables SQL injection if the application dynamically builds SQL statements. SQL injection is not possible if user data is set using parameters ('?').
NONE
means literals of any kind are not allowed, only parameters and constants are allowed. NUMBERS
mean only numerical and boolean literals are allowed. ALL
means all literals are allowed (default).
See also CREATE CONSTANT
.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. This setting can be appended to the database URL: jdbc:h2:test;ALLOW_LITERALS=NONE
Example:
SET ALLOW_LITERALS NONE
SET AUTOCOMMIT
SET AUTOCOMMIT |
|
Switches auto commit on or off. This setting can be appended to the database URL: jdbc:h2:test;AUTOCOMMIT=OFF
- however this will not work as expected when using a connection pool (the connection pool manager will re-enable autocommit when returning the connection to the pool, so autocommit will only be disabled the first time the connection is used.
Example:
SET AUTOCOMMIT OFF
SET CACHE_SIZE
SET CACHE_SIZE int |
Sets the size of the cache in KB (each KB being 1024 bytes) for the current database. The default value is 16384 (16 MB). The value is rounded to the next higher power of two. Depending on the virtual machine, the actual memory required may be higher.
This setting is persistent and affects all connections as there is only one cache per database. Using a very small value (specially 0) will reduce performance a lot. This setting only affects the database engine (the server in a client/server environment). It has no effect for in-memory databases.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. This setting can be appended to the database URL: jdbc:h2:test;CACHE_SIZE=8192
Example:
SET CACHE_SIZE 8192
SET CLUSTER
SET CLUSTER serverListString |
This command should not be used directly by an application, the statement is executed automatically by the system. The behavior may change in future releases. Sets the cluster server list. An empty string switches off the cluster mode. Switching on the cluster mode requires admin rights, but any user can switch it off (this is automatically done when the client detects the other server is not responding).
This command is effective immediately, but does not commit an open transaction.
Example:
SET CLUSTER ''
SET BINARY_COLLATION
SET BINARY_COLLATION |
UNSIGNED | ||
SIGNED |
Sets the collation used for comparing BINARY
columns, the default is SIGNED
for version 1.3 and older, and UNSIGNED
for version 1.4 and newer. This command can only be executed if there are no tables defined.
Admin rights are required to execute this command. This command commits an open transaction. This setting is persistent.
Example:
SET BINARY_COLLATION SIGNED
SET COLLATION
Sets the collation used for comparing strings. This command can only be executed if there are no tables defined. See java.text.Collator
for details about the supported collations and the STRENGTH
(PRIMARY
is usually case- and umlaut-insensitive; SECONDARY
is case-insensitive but umlaut-sensitive; TERTIARY
is both case- and umlaut-sensitive; IDENTICAL
is sensitive to all differences and only affects ordering).
The ICU4J
collator is used if it is in the classpath. It is also used if the collation name starts with ICU4J_
(in that case, the ICU4J
must be in the classpath, otherwise an exception is thrown). The default collator is used if the collation name starts with DEFAULT_
(even if ICU4J
is in the classpath).
Admin rights are required to execute this command. This command commits an open transaction. This setting is persistent.
Example:
SET COLLATION ENGLISH
SET COMPRESS_LOB
SET COMPRESS_LOB |
|
Sets the compression algorithm for BLOB
and CLOB
data. Compression is usually slower, but needs less disk space. LZF
is faster but uses more space.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent.
Example:
SET COMPRESS_LOB LZF
SET DATABASE_EVENT_LISTENER
SET DATABASE_EVENT_LISTENER classNameString |
Sets the event listener class. An empty string ('') means no listener should be used. This setting is not persistent.
Admin rights are required to execute this command, except if it is set when opening the database (in this case it is reset just after opening the database). This setting can be appended to the database URL: jdbc:h2:test;DATABASE_EVENT_LISTENER='sample.MyListener'
Example:
SET DATABASE_EVENT_LISTENER 'sample.MyListener'
SET DB_CLOSE_DELAY
SET DB_CLOSE_DELAY int |
Sets the delay for closing a database if all connections are closed. The value -1 means the database is never closed until the close delay is set to some other value or SHUTDOWN
is called. The value 0 means no delay (default; the database is closed if the last connection to it is closed). Values 1 and larger mean the number of seconds the database is left open after closing the last connection.
If the application exits normally or System.exit is called, the database is closed immediately, even if a delay is set.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. This setting can be appended to the database URL: jdbc:h2:test;DB_CLOSE_DELAY=-1
Example:
SET DB_CLOSE_DELAY -1
SET DEFAULT_LOCK_TIMEOUT
SET DEFAULT LOCK_TIMEOUT int |
Sets the default lock timeout (in milliseconds) in this database that is used for the new sessions. The default value for this setting is 1000 (one second).
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent.
Example:
SET DEFAULT_LOCK_TIMEOUT 5000
SET DEFAULT_TABLE_TYPE
SET DEFAULT_TABLE_TYPE |
|
Sets the default table storage type that is used when creating new tables. Memory tables are kept fully in the main memory (including indexes), however the data is still stored in the database file. The size of memory tables is limited by the memory. The default is CACHED
.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. It has no effect for in-memory databases.
Example:
SET DEFAULT_TABLE_TYPE MEMORY
SET EXCLUSIVE
SET EXCLUSIVE |
|
Switched the database to exclusive mode (1, 2) and back to normal mode (0).
In exclusive mode, new connections are rejected, and operations by other connections are paused until the exclusive mode is disabled. When using the value 1, existing connections stay open. When using the value 2, all existing connections are closed (and current transactions are rolled back) except the connection that executes SET EXCLUSIVE
. Only the connection that set the exclusive mode can disable it. When the connection is closed, it is automatically disabled.
Admin rights are required to execute this command. This command commits an open transaction.
Example:
SET EXCLUSIVE 1
SET IGNORECASE
SET IGNORECASE |
|
If IGNORECASE
is enabled, text columns in newly created tables will be case-insensitive. Already existing tables are not affected. The effect of case-insensitive columns is similar to using a collation with strength PRIMARY
. Case-insensitive columns are compared faster than when using a collation. String literals and parameters are however still considered case sensitive even if this option is set.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. This setting can be appended to the database URL: jdbc:h2:test;IGNORECASE=TRUE
Example:
SET IGNORECASE TRUE
SET JAVA_OBJECT_SERIALIZER
Sets the object used to serialize and deserialize java objects being stored in column of type OTHER
. The serializer class must be public and implement org.h2.api.JavaObjectSerializer
. Inner classes are not supported. The class must be available in the classpath of the database engine (when using the server mode, it must be both in the classpath of the server and the client). This command can only be executed if there are no tables defined.
Admin rights are required to execute this command. This command commits an open transaction. This setting is persistent. This setting can be appended to the database URL: jdbc:h2:test;JAVA_OBJECT_SERIALIZER='com.acme.SerializerClassName'
Example:
SET JAVA_OBJECT_SERIALIZER 'com.acme.SerializerClassName'
SET LOG
SET LOG int |
Sets the transaction log mode. The values 0, 1, and 2 are supported, the default is 2. This setting affects all connections.
LOG
0 means the transaction log is disabled completely. It is the fastest mode, but also the most dangerous: if the process is killed while the database is open in this mode, the data might be lost. It must only be used if this is not a problem, for example when initially loading a database, or when running tests.
LOG
1 means the transaction log is enabled, but FileDescriptor.sync is disabled. This setting is about half as fast as with LOG
0. This setting is useful if no protection against power failure is required, but the data must be protected against killing the process.
LOG
2 (the default) means the transaction log is enabled, and FileDescriptor.sync is called for each checkpoint. This setting is about half as fast as LOG
1. Depending on the file system, this will also protect against power failure in the majority if cases.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is not persistent. This setting can be appended to the database URL: jdbc:h2:test;LOG=0
Example:
SET LOG 1
SET LOCK_MODE
SET LOCK_MODE int |
Sets the lock mode. The values 0, 1, 2, and 3 are supported. The default is 3 (READ_COMMITTED
). This setting affects all connections.
The value 0 means no locking (should only be used for testing; also known as READ_UNCOMMITTED
). Please note that using SET LOCK_MODE
0 while at the same time using multiple connections may result in inconsistent transactions.
The value 1 means table level locking (also known as SERIALIZABLE
).
The value 2 means table level locking with garbage collection (if the application does not close all connections).
The value 3 means table level locking, but read locks are released immediately (default; also known as READ_COMMITTED
).
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. This setting can be appended to the database URL: jdbc:h2:test;LOCK_MODE=3
Example:
SET LOCK_MODE 1
SET LOCK_TIMEOUT
SET LOCK_TIMEOUT int |
Sets the lock timeout (in milliseconds) for the current session. The default value for this setting is 1000 (one second).
This command does not commit a transaction, and rollback does not affect it. This setting can be appended to the database URL: jdbc:h2:test;LOCK_TIMEOUT=10000
Example:
SET LOCK_TIMEOUT 1000
SET MAX_LENGTH_INPLACE_LOB
SET MAX_LENGTH_INPLACE_LOB int |
Sets the maximum size of an in-place LOB
object.
This is the maximum length of an LOB
that is stored with the record itself, and the default value is 128.
This setting has no effect for in-memory databases.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent.
Example:
SET MAX_LENGTH_INPLACE_LOB 128
SET MAX_LOG_SIZE
SET MAX_LOG_SIZE int |
Sets the maximum size of the transaction log, in megabytes. If the log is larger, and if there is no open transaction, the transaction log is truncated. If there is an open transaction, the transaction log will continue to grow however. The default max size is 16 MB. This setting has no effect for in-memory databases.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent.
Example:
SET MAX_LOG_SIZE 2
SET MAX_MEMORY_ROWS
SET MAX_MEMORY_ROWS int |
The maximum number of rows in a result set that are kept in-memory. If more rows are read, then the rows are buffered to disk. The default value is 10000.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. It has no effect for in-memory databases.
Example:
SET MAX_MEMORY_ROWS 1000
SET MAX_MEMORY_UNDO
SET MAX_MEMORY_UNDO int |
The maximum number of undo records per a session that are kept in-memory. If a transaction is larger, the records are buffered to disk. The default value is 50000. Changes to tables without a primary key can not be buffered to disk. This setting is not supported when using multi-version concurrency.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. It has no effect for in-memory databases.
Example:
SET MAX_MEMORY_UNDO 1000
SET MAX_OPERATION_MEMORY
SET MAX_OPERATION_MEMORY int |
Sets the maximum memory used for large operations (delete and insert), in bytes. Operations that use more memory are buffered to disk, slowing down the operation. The default max size is 100000. 0 means no limit.
This setting is not persistent. Admin rights are required to execute this command, as it affects all connections. It has no effect for in-memory databases. This setting can be appended to the database URL: jdbc:h2:test;MAX_OPERATION_MEMORY=10000
Example:
SET MAX_OPERATION_MEMORY 0
SET MODE
SET MODE |
|
Changes to another database compatibility mode. For details, see Compatibility Modes in the feature section.
This setting is not persistent. Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting can be appended to the database URL: jdbc:h2:test;MODE=MYSQL
Example:
SET MODE HSQLDB
SET MULTI_THREADED
SET MULTI_THREADED |
|
Enabled (1) or disabled (0) multi-threading inside the database engine. By default, this setting is disabled. Currently, enabling this is experimental only.
This is a global setting, which means it is not possible to open multiple databases with different modes at the same time in the same virtual machine. This setting is not persistent, however the value is kept until the virtual machine exits or it is changed.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting can be appended to the database URL: jdbc:h2:test;MULTI_THREADED=1
Example:
SET MULTI_THREADED 1
SET OPTIMIZE_REUSE_RESULTS
SET OPTIMIZE_REUSE_RESULTS |
|
Enabled (1) or disabled (0) the result reuse optimization. If enabled, subqueries and views used as subqueries are only re-run if the data in one of the tables was changed. This option is enabled by default.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting can be appended to the database URL: jdbc:h2:test;OPTIMIZE_REUSE_RESULTS=0
Example:
SET OPTIMIZE_REUSE_RESULTS 0
SET PASSWORD
SET PASSWORD string |
Changes the password of the current user. The password must be in single quotes. It is case sensitive and can contain spaces.
This command commits an open transaction.
Example:
SET PASSWORD 'abcstzri!.5'
SET QUERY_STATISTICS
SET QUERY_STATISTICS |
|
Disabled or enables query statistics gathering for the whole database. The statistics are reflected in the INFORMATION_SCHEMA.QUERY_STATISTICS
meta-table.
This setting is not persistent. This command commits an open transaction. Admin rights are required to execute this command, as it affects all connections.
Example:
SET QUERY_STATISTICS FALSE
SET QUERY_TIMEOUT
SET QUERY_TIMEOUT int |
Set the query timeout of the current session to the given value. The timeout is in milliseconds. All kinds of statements will throw an exception if they take longer than the given value. The default timeout is 0, meaning no timeout.
This command does not commit a transaction, and rollback does not affect it.
Example:
SET QUERY_TIMEOUT 10000
SET REFERENTIAL_INTEGRITY
SET REFERENTIAL_INTEGRITY |
|
Disabled or enables referential integrity checking for the whole database. Enabling it does not check existing data. Use ALTER TABLE SET
to disable it only for one table.
This setting is not persistent. This command commits an open transaction. Admin rights are required to execute this command, as it affects all connections.
Example:
SET REFERENTIAL_INTEGRITY FALSE
SET RETENTION_TIME
SET RETENTION_TIME int |
This property is only used when using the MVStore
storage engine. How long to retain old, persisted data, in milliseconds. The default is 45000 (45 seconds), 0 means overwrite data as early as possible. It is assumed that a file system and hard disk will flush all write buffers within this time. Using a lower value might be dangerous, unless the file system and hard disk flush the buffers earlier. To manually flush the buffers, use CHECKPOINT SYNC
, however please note that according to various tests this does not always work as expected depending on the operating system and hardware.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting is persistent. This setting can be appended to the database URL: jdbc:h2:test;RETENTION_TIME=0
Example:
SET RETENTION_TIME 0
SET SALT HASH
Sets the password salt and hash for the current user. The password must be in single quotes. It is case sensitive and can contain spaces.
This command commits an open transaction.
Example:
SET SALT '00' HASH '1122'
SET SCHEMA
SET SCHEMA schemaName |
Changes the default schema of the current connection. The default schema is used in statements where no schema is set explicitly. The default schema for new connections is PUBLIC
.
This command does not commit a transaction, and rollback does not affect it. This setting can be appended to the database URL: jdbc:h2:test;SCHEMA=ABC
Example:
SET SCHEMA INFORMATION_SCHEMA
SET SCHEMA_SEARCH_PATH
SET SCHEMA_SEARCH_PATH schemaName |
|
Changes the schema search path of the current connection. The default schema is used in statements where no schema is set explicitly. The default schema for new connections is PUBLIC
.
This command does not commit a transaction, and rollback does not affect it. This setting can be appended to the database URL: jdbc:h2:test;SCHEMA_SEARCH_PATH=ABC,DEF
Example:
SET SCHEMA_SEARCH_PATH INFORMATION_SCHEMA, PUBLIC
SET THROTTLE
SET THROTTLE int |
Sets the throttle for the current connection. The value is the number of milliseconds delay after each 50 ms. The default value is 0 (throttling disabled).
This command does not commit a transaction, and rollback does not affect it. This setting can be appended to the database URL: jdbc:h2:test;THROTTLE=50
Example:
SET THROTTLE 200
SET TRACE_LEVEL
SET |
| int |
Sets the trace level for file the file or system out stream. Levels are: 0=off, 1=error, 2=info, 3=debug. The default level is 1 for file and 0 for system out. To use SLF4J
, append ;TRACE_LEVEL_FILE=4
to the database URL when opening the database.
This setting is not persistent. Admin rights are required to execute this command, as it affects all connections. This command does not commit a transaction, and rollback does not affect it. This setting can be appended to the database URL: jdbc:h2:test;TRACE_LEVEL_SYSTEM_OUT=3
Example:
SET TRACE_LEVEL_SYSTEM_OUT 3
SET TRACE_MAX_FILE_SIZE
SET TRACE_MAX_FILE_SIZE int |
Sets the maximum trace file size. If the file exceeds the limit, the file is renamed to .old and a new file is created. If another .old file exists, it is deleted. The default max size is 16 MB.
This setting is persistent. Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting can be appended to the database URL: jdbc:h2:test;TRACE_MAX_FILE_SIZE=3
Example:
SET TRACE_MAX_FILE_SIZE 10
SET UNDO_LOG
SET UNDO_LOG int |
Enables (1) or disables (0) the per session undo log. The undo log is enabled by default. When disabled, transactions can not be rolled back. This setting should only be used for bulk operations that don't need to be atomic.
This command commits an open transaction.
Example:
SET UNDO_LOG 0
SET WRITE_DELAY
SET WRITE_DELAY int |
Set the maximum delay between a commit and flushing the log, in milliseconds. This setting is persistent. The default is 500 ms.
Admin rights are required to execute this command, as it affects all connections. This command commits an open transaction. This setting can be appended to the database URL: jdbc:h2:test;WRITE_DELAY=0
Example:
SET WRITE_DELAY 2000
SHUTDOWN
SHUTDOWN |
|
This statement closes all open connections to the database and closes the database. This command is usually not required, as the database is closed automatically when the last connection to it is closed.
If no option is used, then the database is closed normally. All connections are closed, open transactions are rolled back.
SHUTDOWN COMPACT
fully compacts the database (re-creating the database may further reduce the database size). If the database is closed normally (using SHUTDOWN
or by closing all connections), then the database is also compacted, but only for at most the time defined by the database setting h2.maxCompactTime
in milliseconds (see there).
SHUTDOWN IMMEDIATELY
closes the database files without any cleanup and without compacting.
SHUTDOWN DEFRAG
re-orders the pages when closing the database so that table scans are faster.
Admin rights are required to execute this command.
Example:
SHUTDOWN COMPACT
Alias
name
An alias is a name that is only valid in the context of the statement.
Example:
A
And Condition
condition |
|
Value or condition.
Example:
ID=1 AND NAME='Hi'
Array
( |
| ) |
An array of values. An empty array is '()'. Trailing commas are ignored. An array with one element must contain a comma to be parsed as an array.
Example:
(1, 2)
(1, )
()
Boolean
TRUE | ||
FALSE |
A boolean value.
Example:
TRUE
Bytes
X ' hex ' |
A binary value. The hex value is not case sensitive.
Example:
X'01FF'
Case
CASE expression WHEN expression THEN expression |
|
| END |
Returns the first expression where the value is equal to the test expression. If no else part is specified, return NULL
.
Example:
CASE CNT WHEN 0 THEN 'No' WHEN 1 THEN 'One' ELSE 'Some' END
Case When
CASE WHEN expression THEN expression |
|
| END |
Returns the first expression where the condition is true. If no else part is specified, return NULL
.
Example:
CASE WHEN CNT<10 THEN 'Low' ELSE 'High' END
Cipher
AES
Only the algorithm AES
(AES-128
) is supported currently.
Example:
AES
Column Definition
columnName dataType |
|
|
|
|
|
|
|
Default expressions are used if no explicit value was used when adding a row. The computed column expression is evaluated and assigned whenever the row changes.
Identity and auto-increment columns are columns with a sequence as the default. The column declared as the identity columns is implicitly the primary key column of this table (unlike auto-increment columns).
The options PRIMARY KEY, UNIQUE
, and CHECK
are not supported for ALTER
statements.
Check constraints can reference columns of the table, and they can reference objects that exist while the statement is executed. Conditions are only checked when a row is added or modified in the table where the constraint exists.
Example:
CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255) DEFAULT '');
CREATE TABLE TEST(ID BIGINT IDENTITY);
CREATE TABLE TEST(QUANTITY INT, PRICE DECIMAL, AMOUNT DECIMAL AS QUANTITY*PRICE);
Comments
| |||
| |||
|
Comments can be used anywhere in a command and are ignored by the database. Line comments end with a newline. Block comments cannot be nested, but can be multiple lines long.
Example:
// This is a comment
Compare
| |||
| |||
| |||
= | |||
< | |||
> | |||
| |||
&& |
Comparison operator. The operator != is the same as <>. The operator &&
means overlapping; it can only be used with geometry types.
Example:
<>
Condition
| ||||||||||
| ||||||||||
|
Boolean value or condition.
Example:
ID<>2
Condition Right Hand Side
| |||||||||||||||||||||
| |||||||||||||||||||||
| |||||||||||||||||||||
| |||||||||||||||||||||
| |||||||||||||||||||||
| |||||||||||||||||||||
|
The right hand side of a condition.
The conditions IS [ NOT ]
and IS [ NOT ] DISTINCT FROM
are null-safe, meaning NULL
is considered the same as NULL
, and the condition never evaluates to NULL
.
When comparing with LIKE
, the wildcards characters are _
(any one character) and %
(any characters). The database uses an index when comparing with LIKE
except if the operand starts with a wildcard. To search for the characters %
and _
, the characters need to be escaped. The default escape character is \
(backslash). To select no escape character, use ESCAPE ''
(empty string). At most one escape character is allowed. Each character that follows the escape character in the pattern needs to match exactly. Patterns that end with an escape character are invalid and the expression returns NULL
.
When comparing with REGEXP
, regular expression matching is used. See Java Matcher.find
for details.
Example:
LIKE 'Jo%'
Constraint
constraintNameDefinition |
| |||||||||||||||||||
| |||||||||||||||||||
referentialConstraint | |||||||||||||||||||
|
Defines a constraint. The check condition must evaluate to TRUE, FALSE
or NULL
. TRUE
and NULL
mean the operation is to be permitted, and FALSE
means the operation is to be rejected. To prevent NULL
in a column, use NOT NULL
instead of a check constraint.
Example:
PRIMARY KEY(ID, NAME)
Constraint Name Definition
CONSTRAINT |
| newConstraintName |
Defines a constraint name.
Example:
CONSTRAINT CONST_ID
Csv Options
charsetString |
|
Optional parameters for CSVREAD
and CSVWRITE
. Instead of setting the options one by one, all options can be combined into a space separated key-value pairs, as follows: STRINGDECODE('charset=UTF-8 escape=\" fieldDelimiter=\" fieldSeparator=, ' || 'lineComment=# lineSeparator=\n null= rowSeparator=')
. The following options are supported:
caseSensitiveColumnNames
(true or false; disabled by default),
charset
,
escape
,
fieldDelimiter
,
fieldSeparator
,
lineComment
(disabled by default),
lineSeparator
,
null
, Note that an empty value is always treated as null. This feature for compatibility, it is only here to support reading existing CSV
files that contain explicit null
delimiters.
rowSeparator
(not set by default),
preserveWhitespace
(true or false; disabled by default),
writeColumnHeader
(true or false; enabled by default).
For a newline or other special character, use STRINGDECODE
as in the example above. A space needs to be escaped with a backslash ('\ '
), and a backslash needs to be escaped with another backslash ('\\'
). All other characters are not to be escaped, that means newline and tab characters are written as such.
Example:
CALL CSVWRITE('test2.csv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=|');
Data Type
A data type definition.
Example:
INT
Date
DATE ' 2000-01-01 ' |
A date literal. The limitations are the same as for the Java data type java.sql.Date
, but for compatibility with other databases the suggested minimum and maximum years are 0001 and 9999.
Example:
DATE '2004-12-31'
Decimal
|
|
|
A decimal number with fixed precision and scale. Internally, java.lang.BigDecimal
is used. To ensure the floating point representation is used, use CAST
(X AS DOUBLE
). There are some special decimal values: to represent positive infinity, use POWER(0, -1)
; for negative infinity, use (-POWER(0, -1))
; for -0.0, use (-CAST(0 AS DOUBLE))
; for NaN
(not a number), use SQRT(-1)
.
Example:
SELECT -1600.05
SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
Digit
0-9
A digit.
Example:
0
Dollar Quoted String
$ $ anything $ $ |
A string starts and ends with two dollar signs. Two dollar signs are not allowed within the text. A whitespace is required before the first set of dollar signs. No escaping is required within the text.
Example:
$$John's car$$
Expression
andCondition |
|
Value or condition.
Example:
ID=1 OR NAME='Hi'
Factor
term |
|
A value or a numeric factor.
Example:
ID * 10
Hex
|
|
|
The hexadecimal representation of a number or of bytes. Two characters are one byte.
Example:
cafe
Hex Number
| 0x hex |
A number written in hexadecimal notation.
Example:
0xff
Index Column
columnName |
|
|
Indexes this column in ascending or descending order. Usually it is not required to specify the order; however doing so will speed up large queries that order the column in the same way.
Example:
NAME
Int
| number |
The maximum integer number is 2147483647, the minimum is -2147483648.
Example:
10
Long
| number |
Long numbers are between -9223372036854775808 and 9223372036854775807.
Example:
100000
Name
| ||||||||||||||||||||||||
quotedName |
Names are not case sensitive. There is no maximum name length.
Example:
TEST
Null
NULL
NULL
is a value without data type and means 'unknown value'.
Example:
NULL
Number
digit |
|
The maximum length of the number depends on the data type used.
Example:
100
Numeric
decimal | ||
int | ||
long | ||
hexNumber |
The data type of a numeric value is always the lowest possible for the given value. If the number contains a dot this is decimal; otherwise it is int, long, or decimal (depending on the value).
Example:
SELECT -1600.05
SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
Operand
summand |
|
A value or a concatenation of values. In the default mode, the result is NULL
if either parameter is NULL
.
Example:
'Hi' || ' Eva'
Order
|
|
|
Sorts the result by the given column number, or by an expression. If the expression is a single parameter, then the value is interpreted as a column number. Negative column numbers reverse the sort order.
Example:
NAME DESC NULLS LAST
Quoted Name
" anything " |
Quoted names are case sensitive, and can contain spaces. There is no maximum name length. Two double quotes can be used to create a single double quote inside an identifier.
Example:
"FirstName"
Referential Constraint
FOREIGN KEY ( columnName |
| ) |
REFERENCES |
|
|
|
|
Defines a referential constraint. If the table name is not specified, then the same table is referenced. RESTRICT
is the default action. If the referenced columns are not specified, then the primary key columns are used. The required indexes are automatically created if required. Some tables may not be referenced, such as metadata tables.
Example:
FOREIGN KEY(ID) REFERENCES TEST(ID)
Referential Action
CASCADE | ||||||||||
RESTRICT | ||||||||||
| ||||||||||
|
The action CASCADE
will cause conflicting rows in the referencing (child) table to be deleted or updated. RESTRICT
is the default action. As this database does not support deferred checking, RESTRICT
and NO ACTION
will both throw an exception if the constraint is violated. The action SET DEFAULT
will set the column in the referencing (child) table to the default value, while SET NULL
will set it to NULL
.
Example:
FOREIGN KEY(ID) REFERENCES TEST(ID) ON UPDATE CASCADE
Script Compression Encryption
|
|
The compression and encryption algorithm to use for script files. When using encryption, only DEFLATE
and LZF
are supported. LZF
is faster but uses more space.
Example:
COMPRESSION LZF
Select Expression
* | ||||||||||||||||||
| ||||||||||||||||||
|
An expression in a SELECT
statement.
Example:
ID AS VALUE
String
' anything ' |
A string starts and ends with a single quote. Two single quotes can be used to create a single quote inside a string.
Example:
'John''s car'
Summand
factor |
|
A value or a numeric sum.
Please note the text concatenation operator is ||
.
Example:
ID + 20
Table Expression
|
|
|
Joins a table. The join expression is not supported for cross and natural joins. A natural join is an inner join, where the condition is automatically on the columns with the same name.
Example:
TEST AS T LEFT JOIN TEST AS T1 ON T.ID = T1.ID
Values Expression
VALUES ( expression |
| ) |
|
A list of rows that can be used like a table. The column list of the resulting table is C1, C2, and so on.
Example:
SELECT * FROM (VALUES(1, 'Hello'), (2, 'World')) AS V;
Term
value | ||||||||||
columnName | ||||||||||
| ||||||||||
| ||||||||||
Function | ||||||||||
| ||||||||||
| ||||||||||
select | ||||||||||
case | ||||||||||
caseWhen | ||||||||||
|
A value. Parameters can be indexed, for example ?1
meaning the first parameter. Each table has a pseudo-column named _ROWID_
that contains the unique row identifier.
Example:
'Hello'
Time
TIME ' 12:00:00 ' |
A time literal. A value is between plus and minus 2 million hours and has nanosecond resolution.
Example:
TIME '23:59:59'
Timestamp
TIMESTAMP ' 2000-01-01 12:00:00 |
| ' |
A timestamp literal. The limitations are the same as for the Java data type java.sql.Timestamp
, but for compatibility with other databases the suggested minimum and maximum years are 0001 and 9999.
Example:
TIMESTAMP '2005-12-31 23:59:59'
Value
string | ||
dollarQuotedString | ||
numeric | ||
date | ||
time | ||
timestamp | ||
boolean | ||
bytes | ||
array | ||
null |
A literal value of any data type, or null.
Example:
10
Information Schema
The system tables in the schema INFORMATION_SCHEMA
contain the meta data
of all tables in the database as well as the current settings.
Table | Columns |
---|---|
CATALOGS | CATALOG_NAME |
COLLATIONS | NAME, KEY |
COLUMNS | TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, ORDINAL_POSITION, COLUMN_DEFAULT, IS_NULLABLE, DATA_TYPE, CHARACTER_MAXIMUM_LENGTH, CHARACTER_OCTET_LENGTH, NUMERIC_PRECISION, NUMERIC_PRECISION_RADIX, NUMERIC_SCALE, CHARACTER_SET_NAME, COLLATION_NAME, TYPE_NAME, NULLABLE, IS_COMPUTED, SELECTIVITY, CHECK_CONSTRAINT, SEQUENCE_NAME, REMARKS, SOURCE_DATA_TYPE |
COLUMN_PRIVILEGES | GRANTOR, GRANTEE, TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, COLUMN_NAME, PRIVILEGE_TYPE, IS_GRANTABLE |
CONSTANTS | CONSTANT_CATALOG, CONSTANT_SCHEMA, CONSTANT_NAME, DATA_TYPE, REMARKS, SQL, ID |
CONSTRAINTS | CONSTRAINT_CATALOG, CONSTRAINT_SCHEMA, CONSTRAINT_NAME, CONSTRAINT_TYPE, TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, UNIQUE_INDEX_NAME, CHECK_EXPRESSION, COLUMN_LIST, REMARKS, SQL, ID |
CROSS_REFERENCES | PKTABLE_CATALOG, PKTABLE_SCHEMA, PKTABLE_NAME, PKCOLUMN_NAME, FKTABLE_CATALOG, FKTABLE_SCHEMA, FKTABLE_NAME, FKCOLUMN_NAME, ORDINAL_POSITION, UPDATE_RULE, DELETE_RULE, FK_NAME, PK_NAME, DEFERRABILITY |
DOMAINS | DOMAIN_CATALOG, DOMAIN_SCHEMA, DOMAIN_NAME, COLUMN_DEFAULT, IS_NULLABLE, DATA_TYPE, PRECISION, SCALE, TYPE_NAME, SELECTIVITY, CHECK_CONSTRAINT, REMARKS, SQL, ID |
FUNCTION_ALIASES | ALIAS_CATALOG, ALIAS_SCHEMA, ALIAS_NAME, JAVA_CLASS, JAVA_METHOD, DATA_TYPE, TYPE_NAME, COLUMN_COUNT, RETURNS_RESULT, REMARKS, ID, SOURCE |
FUNCTION_COLUMNS | ALIAS_CATALOG, ALIAS_SCHEMA, ALIAS_NAME, JAVA_CLASS, JAVA_METHOD, COLUMN_COUNT, POS, COLUMN_NAME, DATA_TYPE, TYPE_NAME, PRECISION, SCALE, RADIX, NULLABLE, COLUMN_TYPE, REMARKS, COLUMN_DEFAULT |
HELP | ID, SECTION, TOPIC, SYNTAX, TEXT |
INDEXES | TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, NON_UNIQUE, INDEX_NAME, ORDINAL_POSITION, COLUMN_NAME, CARDINALITY, PRIMARY_KEY, INDEX_TYPE_NAME, IS_GENERATED, INDEX_TYPE, ASC_OR_DESC, PAGES, FILTER_CONDITION, REMARKS, SQL, ID, SORT_TYPE, CONSTRAINT_NAME, INDEX_CLASS |
IN_DOUBT | TRANSACTION, STATE |
LOCKS | TABLE_SCHEMA, TABLE_NAME, SESSION_ID, LOCK_TYPE |
QUERY_STATISTICS | SQL_STATEMENT, EXECUTION_COUNT, MIN_EXECUTION_TIME, MAX_EXECUTION_TIME, CUMULATIVE_EXECUTION_TIME, AVERAGE_EXECUTION_TIME, STD_DEV_EXECUTION_TIME, MIN_ROW_COUNT, MAX_ROW_COUNT, CUMULATIVE_ROW_COUNT, AVERAGE_ROW_COUNT, STD_DEV_ROW_COUNT |
RIGHTS | GRANTEE, GRANTEETYPE, GRANTEDROLE, RIGHTS, TABLE_SCHEMA, TABLE_NAME, ID |
ROLES | NAME, REMARKS, ID |
SCHEMATA | CATALOG_NAME, SCHEMA_NAME, SCHEMA_OWNER, DEFAULT_CHARACTER_SET_NAME, DEFAULT_COLLATION_NAME, IS_DEFAULT, REMARKS, ID |
SEQUENCES | SEQUENCE_CATALOG, SEQUENCE_SCHEMA, SEQUENCE_NAME, CURRENT_VALUE, INCREMENT, IS_GENERATED, REMARKS, CACHE, MIN_VALUE, MAX_VALUE, IS_CYCLE, ID |
SESSIONS | ID, USER_NAME, SESSION_START, STATEMENT, STATEMENT_START, CONTAINS_UNCOMMITTED |
SESSION_STATE | KEY, SQL |
SETTINGS | NAME, VALUE |
TABLES | TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, TABLE_TYPE, STORAGE_TYPE, SQL, REMARKS, LAST_MODIFICATION, ID, TYPE_NAME, TABLE_CLASS, ROW_COUNT_ESTIMATE |
TABLE_PRIVILEGES | GRANTOR, GRANTEE, TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, PRIVILEGE_TYPE, IS_GRANTABLE |
TABLE_TYPES | TYPE |
TRIGGERS | TRIGGER_CATALOG, TRIGGER_SCHEMA, TRIGGER_NAME, TRIGGER_TYPE, TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, BEFORE, JAVA_CLASS, QUEUE_SIZE, NO_WAIT, REMARKS, SQL, ID |
TYPE_INFO | TYPE_NAME, DATA_TYPE, PRECISION, PREFIX, SUFFIX, PARAMS, AUTO_INCREMENT, MINIMUM_SCALE, MAXIMUM_SCALE, RADIX, POS, CASE_SENSITIVE, NULLABLE, SEARCHABLE |
USERS | NAME, ADMIN, REMARKS, ID |
VIEWS | TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, VIEW_DEFINITION, CHECK_OPTION, IS_UPDATABLE, STATUS, REMARKS, ID |
Range Table
The range table is a dynamic system table that contains all values from a start to an end value. The table contains one column called X. Both the start and end values are included in the result. The table is used as follows:
Example:
SELECT X FROM SYSTEM_RANGE(1, 10);