help.csv 161.0 KB
Newer Older
1
# Copyright 2004-2018 H2 Group. Multiple-Licensed under the MPL 2.0,
2
# and the EPL 1.0 (http://h2database.com/html/license.html).
Thomas Mueller's avatar
Thomas Mueller committed
3 4 5
# Initial Developer: H2 Group
"SECTION","TOPIC","SYNTAX","TEXT","EXAMPLE"
"Commands (DML)","SELECT","
6
SELECT [ TOP term [ PERCENT ] [ WITH TIES ] ]
7
[ DISTINCT [ ON ( expression [,...] ) ] | ALL ]
8
selectExpression [,...]
9 10
FROM tableExpression [,...] [ WHERE expression ]
[ GROUP BY expression [,...] ] [ HAVING expression ]
11
[ WINDOW { { windowName AS windowSpecification } [,...] } ]
12 13
[ { UNION [ ALL ] | MINUS | EXCEPT | INTERSECT } select ]
[ ORDER BY order [,...] ]
14 15
[ LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] ]
[ [ OFFSET expression { ROW | ROWS } ]
16
    [ FETCH { FIRST | NEXT } [ expression [ PERCENT ] ] { ROW | ROWS }
17
        { ONLY | WITH TIES } ] [ SAMPLE_SIZE rowCountInt ] ]
18
[ FOR UPDATE ]
Thomas Mueller's avatar
Thomas Mueller committed
19 20
","
Selects data from a table or multiple tables.
21 22 23 24
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.
Thomas Mueller's avatar
Thomas Mueller committed
25

26 27 28
Number of rows in output can be limited either with standard OFFSET / FETCH,
with non-standard LIMIT / OFFSET, or with non-standard TOP clauses.
Different clauses cannot be used together.
29
FETCH FIRST/NEXT, LIMIT or TOP limits the number of rows returned by the query (no limit if null or smaller than zero).
30 31 32 33 34 35
If PERCENT is specified number of rows is specified as a percent of the total number of rows
and should be an integer value between 0 and 100 inclusive.
WITH TIES can be used only together with ORDER BY and means that all additional rows that have the same sorting position
as the last row will be also returned.
OFFSET specifies how many rows to skip.
Please note that queries with high offset values can be slow.
36
SAMPLE_SIZE limits the number of rows read for aggregate queries.
37

Owner's avatar
Owner committed
38
Multiple set operators (UNION, INTERSECT, MINUS, EXCEPT) are evaluated
39 40 41
from left to right. For compatibility with other databases and future versions
of H2 please use parentheses.

42 43
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.
Thomas Mueller's avatar
Thomas Mueller committed
44
In this case, aggregate, GROUP BY, DISTINCT queries or joins
45
are not allowed in this case.
Thomas Mueller's avatar
Thomas Mueller committed
46 47
","
SELECT * FROM TEST;
48 49 50 51
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;
52 53
SELECT * FROM TEST OFFSET 1000 ROWS FETCH FIRST 1000 ROWS ONLY;
SELECT A, B FROM TEST ORDER BY A FETCH FIRST 10 ROWS WITH TIES;
Thomas Mueller's avatar
Thomas Mueller committed
54 55 56
SELECT * FROM (SELECT ID, COUNT(*) FROM TEST
    GROUP BY ID UNION SELECT NULL, COUNT(*) FROM TEST)
    ORDER BY 1 NULLS LAST;
57 58
SELECT DISTINCT C1, C2 FROM TEST;
SELECT DISTINCT ON(C1) C1, C2 FROM TEST ORDER BY C1;
Thomas Mueller's avatar
Thomas Mueller committed
59 60 61
"

"Commands (DML)","INSERT","
62
INSERT INTO tableName insertColumnsAndSource
Thomas Mueller's avatar
Thomas Mueller committed
63 64
","
Inserts a new row / new rows into a table.
65 66 67 68

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.
Thomas Mueller's avatar
Thomas Mueller committed
69 70 71 72 73
","
INSERT INTO TEST VALUES(1, 'Hello')
"

"Commands (DML)","UPDATE","
74
UPDATE tableName [ [ AS ] newTableAlias ] SET setClauseList
75
[ WHERE expression ] [ ORDER BY order [,...] ] [ LIMIT expression ]
Thomas Mueller's avatar
Thomas Mueller committed
76 77
","
Updates data in a table.
78
ORDER BY is supported for MySQL compatibility, but it is ignored.
Thomas Mueller's avatar
Thomas Mueller committed
79
","
80 81
UPDATE TEST SET NAME='Hi' WHERE ID=1;
UPDATE PERSON P SET NAME=(SELECT A.NAME FROM ADDRESS A WHERE A.ID=P.ID);
Thomas Mueller's avatar
Thomas Mueller committed
82 83 84
"

"Commands (DML)","DELETE","
85
DELETE [ TOP term ] FROM tableName deleteSearchCondition
Thomas Mueller's avatar
Thomas Mueller committed
86 87
","
Deletes rows form a table.
88
If TOP or LIMIT is specified, at most the specified number of rows are deleted (no limit if null or smaller than zero).
Thomas Mueller's avatar
Thomas Mueller committed
89 90 91 92 93 94 95
","
DELETE FROM TEST WHERE ID=2
"

"Commands (DML)","BACKUP","
BACKUP TO fileNameString
","
Thomas Mueller's avatar
Thomas Mueller committed
96 97
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.
Thomas Mueller's avatar
Thomas Mueller committed
98
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
99 100 101 102 103 104 105
","
BACKUP TO 'backup.zip'
"

"Commands (DML)","CALL","
CALL expression
","
Thomas Mueller's avatar
Thomas Mueller committed
106 107 108
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.
Thomas Mueller's avatar
Thomas Mueller committed
109 110 111 112 113
","
CALL 15*25
"

"Commands (DML)","EXPLAIN","
114 115
EXPLAIN { [ PLAN FOR ] | ANALYZE }
{ select | insert | update | delete | merge }
Thomas Mueller's avatar
Thomas Mueller committed
116 117
","
Shows the execution plan for a statement.
118 119
When using EXPLAIN ANALYZE, the statement is actually executed, and the query plan
will include the actual row scan count for each table.
Thomas Mueller's avatar
Thomas Mueller committed
120 121 122 123 124
","
EXPLAIN SELECT * FROM TEST WHERE ID=1
"

"Commands (DML)","MERGE","
125 126
MERGE INTO tableName [ ( columnName [,...] ) ]
[ KEY ( columnName [,...] ) ]
127
{ VALUES { ( { DEFAULT | expression } [,...] ) } [,...] | select }
Thomas Mueller's avatar
Thomas Mueller committed
128 129 130
","
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
131
row per new row is affected, an exception is thrown.
Thomas Mueller's avatar
Thomas Mueller committed
132 133 134 135
","
MERGE INTO TEST KEY(ID) VALUES(2, 'World')
"

Owner's avatar
Owner committed
136
"Commands (DML)","MERGE USING","
137 138
MERGE INTO targetTableName [ [AS] targetAlias]
USING { ( select ) | sourceTableName }[ [AS] sourceAlias ]
139
ON expression
140
[ WHEN MATCHED THEN
141
    [ UPDATE SET setClauseList ] [ DELETE deleteSearchCondition ] ]
142
[ WHEN NOT MATCHED THEN INSERT insertColumnsAndSource ]
143 144 145 146 147 148
","
Updates or deletes existing rows, and insert rows that don't exist. The ON clause
specifies the matching column expression and must be specified. If more than one row
is updated per input row, an exception is thrown.
If the source data contains duplicate rows (specifically those columns used in the
row matching ON clause), then an exception is thrown to prevent two updates applying
149 150 151
to the same target row.
WHEN MATCHED THEN or WHEN NOT MATCHED THEN clauses or both of them in any order should be specified.
If WHEN MATCHED THEN is specified it should contain UPDATE or DELETE clauses of both of them.
152
If statement doesn't need a source table a DUAL table can be substituted.
Owner's avatar
Owner committed
153
","
154
MERGE INTO TARGET_TABLE AS T USING SOURCE_TABLE AS S
155
    ON T.ID = S.ID
156 157 158 159 160 161
    WHEN MATCHED THEN
        UPDATE SET T.COL1 = S.COL1 WHERE T.COL2<>'FINAL'
        DELETE WHERE T.COL2='FINAL'
    WHEN NOT MATCHED THEN
        INSERT (ID,COL1,COL2) VALUES(S.ID,S.COL1,S.COL2)
MERGE INTO TARGET_TABLE AS T USING (SELECT * FROM SOURCE_TABLE) AS S
162
    ON T.ID = S.ID
163 164 165 166 167
    WHEN MATCHED THEN
        UPDATE SET T.COL1 = S.COL1 WHERE T.COL2<>'FINAL'
        DELETE WHERE T.COL2='FINAL'
    WHEN NOT MATCHED THEN
        INSERT (ID,COL1,COL2) VALUES(S.ID,S.COL1,S.COL2)
168
MERGE INTO TARGET_TABLE USING DUAL ON ID = 1
169 170
    WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (1, 'Test')
    WHEN MATCHED THEN UPDATE SET NAME = 'Test'
Owner's avatar
Owner committed
171 172
"

Thomas Mueller's avatar
Thomas Mueller committed
173
"Commands (DML)","RUNSCRIPT","
174 175
RUNSCRIPT FROM fileNameString scriptCompressionEncryption
[ CHARSET charsetString ]
Thomas Mueller's avatar
Thomas Mueller committed
176 177 178 179 180 181
","
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.

182
Instead of a file name, an URL may be used.
183
To read a stream from the classpath, use the prefix 'classpath:'.
184
See the Pluggable File System section on the Advanced page.
185

186
The compression algorithm must match the one used when creating the script.
Thomas Mueller's avatar
Thomas Mueller committed
187 188 189
Instead of a file, an URL may be used.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
190
","
191
RUNSCRIPT FROM 'backup.sql'
192
RUNSCRIPT FROM 'classpath:/com/acme/test.sql'
Thomas Mueller's avatar
Thomas Mueller committed
193 194 195
"

"Commands (DML)","SCRIPT","
196 197
SCRIPT [ SIMPLE ] [ NODATA ] [ NOPASSWORDS ] [ NOSETTINGS ]
[ DROP ] [ BLOCKSIZE blockSizeInt ]
198
[ TO fileNameString scriptCompressionEncryption
199
    [ CHARSET charsetString ] ]
200 201
[ TABLE tableName [, ...] ]
[ SCHEMA schemaName [, ...] ]
Thomas Mueller's avatar
Thomas Mueller committed
202
","
203 204 205 206 207 208 209
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.
Thomas Mueller's avatar
Thomas Mueller committed
210 211
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
212
out-of-line commands.
Thomas Mueller's avatar
Thomas Mueller committed
213
NOSETTINGS turns off dumping the database settings (the SET XXX commands)
214

215
If no 'TO fileName' clause is specified, the
Thomas Mueller's avatar
Thomas Mueller committed
216 217 218 219
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.

220
If a 'TO fileName' clause is specified, then the whole
Thomas Mueller's avatar
Thomas Mueller committed
221
script (including insert statements) is written to this file, and a result set
222
without the insert statements is returned.
Thomas Mueller's avatar
Thomas Mueller committed
223

Thomas Mueller's avatar
Thomas Mueller committed
224 225 226
The password must be in single quotes; it is case sensitive and can contain spaces.

This command locks objects while it is running.
Thomas Mueller's avatar
Thomas Mueller committed
227
Admin rights are required to execute this command.
228

229
When using the TABLE or SCHEMA option, only the selected table(s) / schema(s) are included.
Thomas Mueller's avatar
Thomas Mueller committed
230 231 232 233 234
","
SCRIPT NODATA
"

"Commands (DML)","SHOW","
235 236
SHOW { SCHEMAS | TABLES [ FROM schemaName ] |
    COLUMNS FROM tableName [ FROM schemaName ] }
Thomas Mueller's avatar
Thomas Mueller committed
237 238 239 240 241 242
","
Lists the schemas, tables, or the columns of a table.
","
SHOW TABLES
"

243
"Commands (DML)","WITH","
244 245
WITH [ RECURSIVE ] { name [( columnName [,...] )] AS ( select ) [,...] }
{ select | insert | update | merge | delete | createTable }
246
","
247
Can be used to create a recursive or non-recursive query (common table expression).
248
For recursive queries the first select has to be a UNION.
249
One or more common table entries can be referred to by name.
250
Column name declarations are now optional - the column names will be inferred from the named select queries.
251
The final action in a WITH statement can be a select, insert, update, merge, delete or create table.
252
","
253
WITH RECURSIVE cte(n) AS (
254 255 256
        SELECT 1
    UNION ALL
        SELECT n + 1
257
        FROM cte
258 259
        WHERE n < 100
)
260 261 262 263
SELECT sum(n) FROM cte;

Example 2:
WITH cte1 AS (
264
        SELECT 1 AS FIRST_COLUMN
265 266
), cte2 AS (
        SELECT FIRST_COLUMN+1 AS FIRST_COLUMN FROM cte1
267
)
268
SELECT sum(FIRST_COLUMN) FROM cte2;
269 270
"

Thomas Mueller's avatar
Thomas Mueller committed
271
"Commands (DDL)","ALTER INDEX RENAME","
272
ALTER INDEX [ IF EXISTS ] indexName RENAME TO newIndexName
Thomas Mueller's avatar
Thomas Mueller committed
273
","
Thomas Mueller's avatar
Thomas Mueller committed
274
Renames an index.
Thomas Mueller's avatar
Thomas Mueller committed
275
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
276 277 278 279
","
ALTER INDEX IDXNAME RENAME TO IDX_TEST_NAME
"

280
"Commands (DDL)","ALTER SCHEMA RENAME","
281
ALTER SCHEMA [ IF EXISTS ] schema RENAME TO newSchemaName
282 283
","
Renames a schema.
Thomas Mueller's avatar
Thomas Mueller committed
284
This command commits an open transaction in this connection.
285 286 287 288
","
ALTER SCHEMA TEST RENAME TO PRODUCTION
"

Thomas Mueller's avatar
Thomas Mueller committed
289
"Commands (DDL)","ALTER SEQUENCE","
290 291 292
ALTER SEQUENCE [ IF EXISTS ] sequenceName
[ RESTART WITH long ]
[ INCREMENT BY long ]
293 294
[ MINVALUE long | NOMINVALUE | NO MINVALUE ]
[ MAXVALUE long | NOMAXVALUE | NO MAXVALUE ]
295 296
[ CYCLE long | NOCYCLE | NO CYCLE ]
[ CACHE long | NOCACHE | NO CACHE ]
Thomas Mueller's avatar
Thomas Mueller committed
297
","
298
Changes the parameters of a sequence.
Thomas Mueller's avatar
Thomas Mueller committed
299
This command does not commit the current transaction; however the new value is used by other
Thomas Mueller's avatar
Thomas Mueller committed
300 301 302 303 304 305
transactions immediately, and rolling back this command has no effect.
","
ALTER SEQUENCE SEQ_ID RESTART WITH 1000
"

"Commands (DDL)","ALTER TABLE ADD","
306
ALTER TABLE [ IF EXISTS ] tableName ADD [ COLUMN ]
307 308
{ [ IF NOT EXISTS ] columnName columnDefinition
    | ( { columnName columnDefinition | constraint } [,...] ) }
309
[ { { BEFORE | AFTER } columnName } | FIRST ]
Thomas Mueller's avatar
Thomas Mueller committed
310
","
Thomas Mueller's avatar
Thomas Mueller committed
311
Adds a new column to a table.
Thomas Mueller's avatar
Thomas Mueller committed
312
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
313 314 315 316 317
","
ALTER TABLE TEST ADD CREATEDATE TIMESTAMP
"

"Commands (DDL)","ALTER TABLE ADD CONSTRAINT","
318
ALTER TABLE [ IF EXISTS ] tableName ADD constraint [ CHECK | NOCHECK ]
Thomas Mueller's avatar
Thomas Mueller committed
319 320 321
","
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).
Thomas Mueller's avatar
Thomas Mueller committed
322
The required indexes are automatically created if they don't exist yet.
Thomas Mueller's avatar
Thomas Mueller committed
323
It is not possible to disable checking for unique constraints.
Thomas Mueller's avatar
Thomas Mueller committed
324
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
325 326 327 328
","
ALTER TABLE TEST ADD CONSTRAINT NAME_UNIQUE UNIQUE(NAME)
"

329
"Commands (DDL)","ALTER TABLE RENAME CONSTRAINT","
330 331
ALTER TABLE [ IF EXISTS ] tableName RENAME oldConstraintName
TO newConstraintName
332 333 334 335 336 337 338
","
Renames a constraint.
This command commits an open transaction in this connection.
","
ALTER TABLE TEST RENAME CONSTRAINT FOO TO BAR
"

339
"Commands (DDL)","ALTER TABLE ALTER COLUMN","
340
ALTER TABLE [ IF EXISTS ] tableName ALTER COLUMN columnName
341
{ { columnDefinition }
342 343 344 345
    | { RENAME TO name }
    | { RESTART WITH long }
    | { SELECTIVITY int }
    | { SET DEFAULT expression }
346
    | { SET ON UPDATE expression }
347
    | { SET NULL }
348
    | { SET NOT NULL }
349 350
    | { SET { VISIBLE | INVISIBLE } }
    | { DROP { DEFAULT | ON UPDATE } } }
Thomas Mueller's avatar
Thomas Mueller committed
351
","
352 353
Changes the data type of a column, rename a column,
change the identity value, or change the selectivity.
Thomas Mueller's avatar
Thomas Mueller committed
354

355
Changing the data type fails if the data can not be converted.
Thomas Mueller's avatar
Thomas Mueller committed
356

357 358 359
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.
Thomas Mueller's avatar
Thomas Mueller committed
360

361 362 363 364
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.
Thomas Mueller's avatar
Thomas Mueller committed
365

366
SET DEFAULT changes the default value of a column.
Thomas Mueller's avatar
Thomas Mueller committed
367

368 369
SET ON UPDATE changes the value that is set on update if value for this column is not specified in update statement.

370
SET NULL sets a column to allow NULL. The row may not be part of a primary key.
Thomas Mueller's avatar
Thomas Mueller committed
371
Single column indexes on this column are dropped.
372 373 374

SET NOT NULL sets a column to not allow NULL. Rows may not contains NULL in this column.

375 376 377
SET INVISIBLE makes the column hidden, i.e. it will not appear in SELECT * results.
SET VISIBLE has the reverse effect.

378 379 380 381
DROP DEFAULT removes the default value of a column.

DROP ON UPDATE removes the value that is set on update of a column.

Thomas Mueller's avatar
Thomas Mueller committed
382
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
383
","
384 385 386 387 388 389 390
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;
391 392
ALTER TABLE TEST ALTER COLUMN NAME SET VISIBLE;
ALTER TABLE TEST ALTER COLUMN NAME SET INVISIBLE;
Thomas Mueller's avatar
Thomas Mueller committed
393 394 395
"

"Commands (DDL)","ALTER TABLE DROP COLUMN","
396
ALTER TABLE [ IF EXISTS ] tableName DROP COLUMN [ IF EXISTS ]
397
columnName [,...] | ( columnName [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
398
","
399
Removes column(s) from a table.
Thomas Mueller's avatar
Thomas Mueller committed
400
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
401 402
","
ALTER TABLE TEST DROP COLUMN NAME
403
ALTER TABLE TEST DROP COLUMN NAME1, NAME2
404
ALTER TABLE TEST DROP COLUMN (NAME1, NAME2)
Thomas Mueller's avatar
Thomas Mueller committed
405 406 407
"

"Commands (DDL)","ALTER TABLE DROP CONSTRAINT","
408 409
ALTER TABLE [ IF EXISTS ] tableName DROP
{ CONSTRAINT [ IF EXISTS ] constraintName | PRIMARY KEY }
Thomas Mueller's avatar
Thomas Mueller committed
410 411
","
Removes a constraint or a primary key from a table.
Thomas Mueller's avatar
Thomas Mueller committed
412
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
413 414 415 416 417
","
ALTER TABLE TEST DROP CONSTRAINT UNIQUE_NAME
"

"Commands (DDL)","ALTER TABLE SET","
418
ALTER TABLE [ IF EXISTS ] tableName SET REFERENTIAL_INTEGRITY
419
{ FALSE | TRUE } [ CHECK | NOCHECK ]
Thomas Mueller's avatar
Thomas Mueller committed
420 421 422 423 424 425
","
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.
426

Thomas Mueller's avatar
Thomas Mueller committed
427
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
428 429 430 431 432
","
ALTER TABLE TEST SET REFERENTIAL_INTEGRITY FALSE
"

"Commands (DDL)","ALTER TABLE RENAME","
433
ALTER TABLE [ IF EXISTS ] tableName RENAME TO newName
Thomas Mueller's avatar
Thomas Mueller committed
434
","
Thomas Mueller's avatar
Thomas Mueller committed
435
Renames a table.
Thomas Mueller's avatar
Thomas Mueller committed
436
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
437 438 439 440 441
","
ALTER TABLE TEST RENAME TO MY_DATA
"

"Commands (DDL)","ALTER USER ADMIN","
442
ALTER USER userName ADMIN { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
443
","
Thomas Mueller's avatar
Thomas Mueller committed
444 445 446 447
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.
Thomas Mueller's avatar
Thomas Mueller committed
448
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
449 450 451 452 453 454 455
","
ALTER USER TOM ADMIN TRUE
"

"Commands (DDL)","ALTER USER RENAME","
ALTER USER userName RENAME TO newUserName
","
Thomas Mueller's avatar
Thomas Mueller committed
456 457 458 459
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.
Thomas Mueller's avatar
Thomas Mueller committed
460
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
461
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
462 463 464 465 466
","
ALTER USER TOM RENAME TO THOMAS
"

"Commands (DDL)","ALTER USER SET PASSWORD","
467
ALTER USER userName SET { PASSWORD string | SALT bytes HASH bytes }
Thomas Mueller's avatar
Thomas Mueller committed
468
","
Thomas Mueller's avatar
Thomas Mueller committed
469 470 471 472 473 474
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.
Thomas Mueller's avatar
Thomas Mueller committed
475
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
476 477 478 479
","
ALTER USER SA SET PASSWORD 'rioyxlgt'
"

480
"Commands (DDL)","ALTER VIEW RECOMPILE","
481
ALTER VIEW [ IF EXISTS ] viewName RECOMPILE
Thomas Mueller's avatar
Thomas Mueller committed
482 483
","
Recompiles a view after the underlying tables have been changed or created.
Thomas Mueller's avatar
Thomas Mueller committed
484
This command is used for views created using CREATE FORCE VIEW.
Thomas Mueller's avatar
Thomas Mueller committed
485
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
486 487 488 489
","
ALTER VIEW ADDRESS_VIEW RECOMPILE
"

490 491 492 493 494 495 496 497 498
"Commands (DDL)","ALTER VIEW RENAME","
ALTER VIEW [ IF EXISTS ] viewName RENAME TO newName
","
Renames a view.
This command commits an open transaction in this connection.
","
ALTER VIEW TEST RENAME TO MY_VIEW
"

Thomas Mueller's avatar
Thomas Mueller committed
499
"Commands (DDL)","ANALYZE","
500
ANALYZE [ TABLE tableName ] [ SAMPLE_SIZE rowCountInt ]
Thomas Mueller's avatar
Thomas Mueller committed
501
","
502 503 504
Updates the selectivity statistics of tables.
If no table name is given, all tables are analyzed.
The selectivity is used by the
Thomas Mueller's avatar
Thomas Mueller committed
505 506 507 508 509
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.
510

Thomas Mueller's avatar
Thomas Mueller committed
511
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
512 513 514 515 516
","
ANALYZE SAMPLE_SIZE 1000
"

"Commands (DDL)","COMMENT","
517 518 519 520 521
COMMENT ON
{ { COLUMN [ schemaName. ] tableName.columnName }
    | { { TABLE | VIEW | CONSTANT | CONSTRAINT | ALIAS | INDEX | ROLE
    | SCHEMA | SEQUENCE | TRIGGER | USER | DOMAIN } [ schemaName. ] objectName } }
IS expression
Thomas Mueller's avatar
Thomas Mueller committed
522
","
Thomas Mueller's avatar
Thomas Mueller committed
523 524 525
Sets the comment of a database object. Use NULL to remove the comment.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
526
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
527 528 529 530 531
","
COMMENT ON TABLE TEST IS 'Table used for testing'
"

"Commands (DDL)","CREATE AGGREGATE","
532
CREATE AGGREGATE [ IF NOT EXISTS ] newAggregateName FOR className
Thomas Mueller's avatar
Thomas Mueller committed
533 534 535
","
Creates a new user-defined aggregate function. The method name must be the full
qualified class name. The class must implement the interface
536
""org.h2.api.AggregateFunction"".
Thomas Mueller's avatar
Thomas Mueller committed
537 538

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
539
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
540
","
541
CREATE AGGREGATE SIMPLE_MEDIAN FOR ""com.acme.db.Median""
Thomas Mueller's avatar
Thomas Mueller committed
542 543 544
"

"Commands (DDL)","CREATE ALIAS","
Thomas Mueller's avatar
Thomas Mueller committed
545
CREATE ALIAS [ IF NOT EXISTS ] newFunctionAliasName [ DETERMINISTIC ]
Thomas Mueller's avatar
Thomas Mueller committed
546
[ NOBUFFER ] { FOR classAndMethodName | AS sourceCodeString }
Thomas Mueller's avatar
Thomas Mueller committed
547
","
548 549 550 551 552 553
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.
554 555 556

The method name must be the full qualified class and method name,
and may optionally include the parameter classes as in
557
""java.lang.Integer.parseInt(java.lang.String, int)"". The class and the method
558
must both be public, and the method must be static. The class must be available
559
in the classpath of the database engine (when using the server mode,
560
it must be in the classpath of the server).
Thomas Mueller's avatar
Thomas Mueller committed
561

562 563
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.
564 565
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
566 567
as dollar quoted text to avoid escaping problems. If import statements are used,
then the tag @CODE must be added before the method.
568

569
If the method throws an SQLException, it is directly re-thrown to the calling application;
Thomas Mueller's avatar
Thomas Mueller committed
570 571
all other exceptions are first converted to a SQLException.

572
If the first parameter of the Java function is a ""java.sql.Connection"", then a
Thomas Mueller's avatar
Thomas Mueller committed
573 574 575
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.
576

Thomas Mueller's avatar
Thomas Mueller committed
577
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
578
This command commits an open transaction in this connection.
579 580

If you have the Groovy jar in your classpath, it is also possible to write methods using Groovy.
Thomas Mueller's avatar
Thomas Mueller committed
581 582 583 584 585
","
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');
586 587
CREATE ALIAS REVERSE AS $$ String reverse(String s) { return new StringBuilder(s).reverse().toString(); } $$;
CALL REVERSE('Test');
588 589 590 591 592
CREATE ALIAS tr AS $$@groovy.transform.CompileStatic
    static String tr(String str, String sourceSet, String replacementSet){
        return str.tr(sourceSet, replacementSet);
    }
$$
Thomas Mueller's avatar
Thomas Mueller committed
593 594 595
"

"Commands (DDL)","CREATE CONSTANT","
596
CREATE CONSTANT [ IF NOT EXISTS ] newConstantName VALUE expression
Thomas Mueller's avatar
Thomas Mueller committed
597
","
Thomas Mueller's avatar
Thomas Mueller committed
598
Creates a new constant.
Thomas Mueller's avatar
Thomas Mueller committed
599
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
600 601 602 603 604
","
CREATE CONSTANT ONE VALUE 1
"

"Commands (DDL)","CREATE DOMAIN","
605 606 607
CREATE DOMAIN [ IF NOT EXISTS ] newDomainName AS dataType
[ DEFAULT expression ] [ [ NOT ] NULL ] [ SELECTIVITY selectivity ]
[ CHECK condition ]
Thomas Mueller's avatar
Thomas Mueller committed
608 609
","
Creates a new data type (domain). The check condition must evaluate to true or
Thomas Mueller's avatar
Thomas Mueller committed
610
to NULL (to prevent NULL, use ""NOT NULL""). In the condition, the term VALUE refers
Thomas Mueller's avatar
Thomas Mueller committed
611
to the value being tested.
612

Thomas Mueller's avatar
Thomas Mueller committed
613 614
Domains are usable within the whole database. They can not be created in a specific schema.

Thomas Mueller's avatar
Thomas Mueller committed
615
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
616 617 618 619 620
","
CREATE DOMAIN EMAIL AS VARCHAR(255) CHECK (POSITION('@', VALUE) > 1)
"

"Commands (DDL)","CREATE INDEX","
621
CREATE
Thomas Mueller's avatar
Thomas Mueller committed
622
{ [ UNIQUE ] [ HASH | SPATIAL] INDEX [ [ IF NOT EXISTS ] newIndexName ]
623 624
    | PRIMARY KEY [ HASH ] }
ON tableName ( indexColumn [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
625
","
Thomas Mueller's avatar
Thomas Mueller committed
626
Creates a new index.
Thomas Mueller's avatar
Thomas Mueller committed
627
This command commits an open transaction in this connection.
628

Thomas Mueller's avatar
Thomas Mueller committed
629
Hash indexes are meant for in-memory databases and memory tables (CREATE MEMORY TABLE).
630 631
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).
Thomas Mueller's avatar
Thomas Mueller committed
632
Non-unique keys are supported.
633
Spatial indexes are supported only on Geometry columns.
Thomas Mueller's avatar
Thomas Mueller committed
634 635 636 637 638
","
CREATE INDEX IDXNAME ON TEST(NAME)
"

"Commands (DDL)","CREATE LINKED TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
639
CREATE [ FORCE ] [ [ GLOBAL | LOCAL ] TEMPORARY ]
Thomas Mueller's avatar
Thomas Mueller committed
640
LINKED TABLE [ IF NOT EXISTS ]
641 642
name ( driverString, urlString, userString, passwordString,
[ originalSchemaString, ] originalTableString ) [ EMIT UPDATES | READONLY ]
Thomas Mueller's avatar
Thomas Mueller committed
643 644 645 646 647
","
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.

648 649 650
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
Thomas Mueller's avatar
Thomas Mueller committed
651 652
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
653
work. Linked tables to the same database share one connection.
654

655 656
READONLY - is set, the remote table may not be updated. This is enforced by H2.

Thomas Mueller's avatar
Thomas Mueller committed
657 658 659
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).

660
If a query is used instead of the original table name, the table is read only.
661
Queries must be enclosed in parenthesis: ""(SELECT * FROM ORDERS)"".
Thomas Mueller's avatar
Thomas Mueller committed
662 663

To use JNDI to get the connection, the driver class must be a
664 665
javax.naming.Context (for example ""javax.naming.InitialContext""), and the URL must
be the resource name (for example ""java:comp/env/jdbc/Test"").
666

Thomas Mueller's avatar
Thomas Mueller committed
667
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
668
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
669
","
670 671
CREATE LINKED TABLE LINK('org.h2.Driver', 'jdbc:h2:test2',
    'sa', 'sa', 'TEST');
Thomas Mueller's avatar
Thomas Mueller committed
672 673 674
CREATE LINKED TABLE LINK('', 'jdbc:h2:test2', 'sa', 'sa',
    '(SELECT * FROM TEST WHERE ID>0)');
CREATE LINKED TABLE LINK('javax.naming.InitialContext',
675 676
    'java:comp/env/jdbc/Test', NULL, NULL,
    '(SELECT * FROM TEST WHERE ID>0)');
Thomas Mueller's avatar
Thomas Mueller committed
677 678 679
"

"Commands (DDL)","CREATE ROLE","
680
CREATE ROLE [ IF NOT EXISTS ] newRoleName
Thomas Mueller's avatar
Thomas Mueller committed
681
","
Thomas Mueller's avatar
Thomas Mueller committed
682
Creates a new role.
Thomas Mueller's avatar
Thomas Mueller committed
683
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
684 685 686 687 688
","
CREATE ROLE READONLY
"

"Commands (DDL)","CREATE SCHEMA","
689 690
CREATE SCHEMA [ IF NOT EXISTS ] name
[ AUTHORIZATION ownerUserName ]
691
[ WITH tableEngineParamName [,...] ]
Thomas Mueller's avatar
Thomas Mueller committed
692 693 694
","
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.
Thomas Mueller's avatar
Thomas Mueller committed
695
Specifying the owner currently has no effect.
696 697
Optional table engine parameters are used when CREATE TABLE command
is run on this schema without having its engine params set.
698

Thomas Mueller's avatar
Thomas Mueller committed
699
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
700 701 702 703 704
","
CREATE SCHEMA TEST_SCHEMA AUTHORIZATION SA
"

"Commands (DDL)","CREATE SEQUENCE","
705
CREATE SEQUENCE [ IF NOT EXISTS ] newSequenceName
706
sequenceOptions
Thomas Mueller's avatar
Thomas Mueller committed
707
","
Thomas Mueller's avatar
Thomas Mueller committed
708 709 710
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.
Thomas Mueller's avatar
Thomas Mueller committed
711 712 713 714 715

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.
Thomas Mueller's avatar
Thomas Mueller committed
716

Thomas Mueller's avatar
Thomas Mueller committed
717
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
718 719 720 721 722
","
CREATE SEQUENCE SEQ_ID
"

"Commands (DDL)","CREATE TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
723 724
CREATE [ CACHED | MEMORY ] [ TEMP | [ GLOBAL | LOCAL ] TEMPORARY ]
TABLE [ IF NOT EXISTS ] name
725
[ ( { columnName columnDefinition | constraint } [,...] ) ]
726 727
[ ENGINE tableEngineName ]
[ WITH tableEngineParamName [,...] ]
728
[ NOT PERSISTENT ] [ TRANSACTIONAL ]
729
[ AS select [ WITH [ NO ] DATA ] ]","
Thomas Mueller's avatar
Thomas Mueller committed
730 731
Creates a new table.

Thomas Mueller's avatar
Thomas Mueller committed
732 733 734 735
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,
Thomas Mueller's avatar
Thomas Mueller committed
736
that means memory tables should not get too large.
737

Thomas Mueller's avatar
Thomas Mueller committed
738 739 740 741 742
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,
743
unless the temporary table is created using CREATE CACHED TABLE.
Thomas Mueller's avatar
Thomas Mueller committed
744

745
The ENGINE option is only required when custom table implementations are used.
746
The table engine class must implement the interface ""org.h2.api.TableEngine"".
747
Any table engine parameters are passed down in the tableEngineParams field of the CreateTableData object.
748

749 750 751
Either ENGINE, or WITH (table engine params), or both may be specified. If ENGINE is not specified
in CREATE TABLE, then the engine specified by DEFAULT_TABLE_ENGINE option of database params is used.

752
Tables with the NOT PERSISTENT modifier are kept fully in memory, and all
753
rows are lost when the database is closed.
Thomas Mueller's avatar
Thomas Mueller committed
754

755 756
The column definition is optional if a query is specified.
In that case the column list of the query is used.
757
If the query is specified its results are inserted into created table unless WITH NO DATA is specified.
758

Thomas Mueller's avatar
Thomas Mueller committed
759 760
This command commits an open transaction, except when using
TRANSACTIONAL (only supported for temporary tables).
Thomas Mueller's avatar
Thomas Mueller committed
761 762 763 764 765
","
CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255))
"

"Commands (DDL)","CREATE TRIGGER","
766 767 768 769 770 771
CREATE TRIGGER [ IF NOT EXISTS ] newTriggerName
{ BEFORE | AFTER | INSTEAD OF }
{ INSERT | UPDATE | DELETE | SELECT | ROLLBACK }
[,...] ON tableName [ FOR EACH ROW ]
[ QUEUE int ] [ NOWAIT ]
{ CALL triggeredClassName | AS sourceCodeString }
Thomas Mueller's avatar
Thomas Mueller committed
772
","
Thomas Mueller's avatar
Thomas Mueller committed
773 774 775 776 777
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).
778

779 780
The sourceCodeString must define a single method with no parameters that returns ""org.h2.api.Trigger"".
See CREATE ALIAS for requirements regarding the compilation.
781 782 783
Alternatively, javax.script.ScriptEngineManager can be used to create an instance of ""org.h2.api.Trigger"".
Currently javascript (included in every JRE) and ruby (with JRuby) are supported.
In that case the source must begin respectively with ""//javascript"" or ""#ruby"".
784

785
BEFORE triggers are called after data conversion is made, default values are set,
786
null and length constraint checks have been made;
787
but before other constraints have been checked.
Thomas Mueller's avatar
Thomas Mueller committed
788
If there are multiple triggers, the order in which they are called is undefined.
789

Thomas Mueller's avatar
Thomas Mueller committed
790
ROLLBACK can be specified in combination with INSERT, UPDATE, and DELETE.
791
Only row based AFTER trigger can be called on ROLLBACK.
792
Exceptions that occur within such triggers are ignored.
793 794
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.
795

796
INSTEAD OF triggers are implicitly row based and behave like BEFORE triggers.
797
Only the first such trigger is called. Such triggers on views are supported.
798
They can be used to make views updatable.
799

Thomas Mueller's avatar
Thomas Mueller committed
800 801
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.
802 803
The trigger is called with both 'old' and 'new' set to null.

804 805 806 807
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.

Thomas Mueller's avatar
Thomas Mueller committed
808 809
Committing or rolling back a transaction within a trigger is not allowed, except for SELECT triggers.

Thomas Mueller's avatar
Thomas Mueller committed
810 811 812
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.

813 814
QUEUE is implemented for syntax compatibility with HSQL and has no effect.

Thomas Mueller's avatar
Thomas Mueller committed
815 816
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.
817

Thomas Mueller's avatar
Thomas Mueller committed
818
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
819
","
820
CREATE TRIGGER TRIG_INS BEFORE INSERT ON TEST FOR EACH ROW CALL ""MyTrigger"";
Thomas Mueller's avatar
Thomas Mueller committed
821
CREATE TRIGGER TRIG_SRC BEFORE INSERT ON TEST AS $$org.h2.api.Trigger create() { return new MyTrigger(""constructorParam""); } $$;
822 823
CREATE TRIGGER TRIG_JS BEFORE INSERT ON TEST AS $$//javascript\nreturn new Packages.MyTrigger(""constructorParam""); $$;
CREATE TRIGGER TRIG_RUBY BEFORE INSERT ON TEST AS $$#ruby\nJava::MyPackage::MyTrigger.new(""constructorParam"") $$;
Thomas Mueller's avatar
Thomas Mueller committed
824 825
"
"Commands (DDL)","CREATE USER","
826 827
CREATE USER [ IF NOT EXISTS ] newUserName
{ PASSWORD string | SALT bytes HASH bytes } [ ADMIN ]
Thomas Mueller's avatar
Thomas Mueller committed
828
","
Thomas Mueller's avatar
Thomas Mueller committed
829 830 831
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.
832

Thomas Mueller's avatar
Thomas Mueller committed
833
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
834
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
835 836 837 838 839
","
CREATE USER GUEST PASSWORD 'abc'
"

"Commands (DDL)","CREATE VIEW","
Thomas Mueller's avatar
Thomas Mueller committed
840
CREATE [ OR REPLACE ] [ FORCE ] VIEW [ IF NOT EXISTS ] newViewName
841
[ ( columnName [,...] ) ] AS select
Thomas Mueller's avatar
Thomas Mueller committed
842 843
","
Creates a new view. If the force option is used, then the view is created even
Thomas Mueller's avatar
Thomas Mueller committed
844
if the underlying table(s) don't exist.
845

Thomas Mueller's avatar
Thomas Mueller committed
846 847 848 849 850
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.

851 852
Views are not updatable except when using 'instead of' triggers.

Thomas Mueller's avatar
Thomas Mueller committed
853
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
854
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
855 856 857 858 859
","
CREATE VIEW TEST_VIEW AS SELECT * FROM TEST WHERE ID < 100
"

"Commands (DDL)","DROP AGGREGATE","
860
DROP AGGREGATE [ IF EXISTS ] aggregateName
Thomas Mueller's avatar
Thomas Mueller committed
861
","
Thomas Mueller's avatar
Thomas Mueller committed
862 863 864
Drops an existing user-defined aggregate function.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
865
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
866
","
867
DROP AGGREGATE SIMPLE_MEDIAN
Thomas Mueller's avatar
Thomas Mueller committed
868 869 870
"

"Commands (DDL)","DROP ALIAS","
871
DROP ALIAS [ IF EXISTS ] existingFunctionAliasName
Thomas Mueller's avatar
Thomas Mueller committed
872
","
Thomas Mueller's avatar
Thomas Mueller committed
873 874 875
Drops an existing function alias.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
876
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
877
","
Thomas Mueller's avatar
Thomas Mueller committed
878
DROP ALIAS MY_SQRT
Thomas Mueller's avatar
Thomas Mueller committed
879 880 881
"

"Commands (DDL)","DROP ALL OBJECTS","
882
DROP ALL OBJECTS [ DELETE FILES ]
Thomas Mueller's avatar
Thomas Mueller committed
883 884 885 886 887
","
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
Thomas Mueller's avatar
Thomas Mueller committed
888 889 890
back.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
891 892 893 894 895
","
DROP ALL OBJECTS
"

"Commands (DDL)","DROP CONSTANT","
896
DROP CONSTANT [ IF EXISTS ] constantName
Thomas Mueller's avatar
Thomas Mueller committed
897
","
Thomas Mueller's avatar
Thomas Mueller committed
898
Drops a constant.
Thomas Mueller's avatar
Thomas Mueller committed
899
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
900 901 902 903 904
","
DROP CONSTANT ONE
"

"Commands (DDL)","DROP DOMAIN","
905
DROP DOMAIN [ IF EXISTS ] domainName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
906
","
Thomas Mueller's avatar
Thomas Mueller committed
907
Drops a data type (domain).
908 909
The command will fail if it is referenced by a column (the default).
Column descriptors are replaced with original definition of specified domain if the CASCADE clause is used.
Thomas Mueller's avatar
Thomas Mueller committed
910
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
911 912 913 914 915
","
DROP DOMAIN EMAIL
"

"Commands (DDL)","DROP INDEX","
916
DROP INDEX [ IF EXISTS ] indexName
Thomas Mueller's avatar
Thomas Mueller committed
917
","
Thomas Mueller's avatar
Thomas Mueller committed
918
Drops an index.
Thomas Mueller's avatar
Thomas Mueller committed
919
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
920 921 922 923 924
","
DROP INDEX IF EXISTS IDXNAME
"

"Commands (DDL)","DROP ROLE","
925
DROP ROLE [ IF EXISTS ] roleName
Thomas Mueller's avatar
Thomas Mueller committed
926
","
Thomas Mueller's avatar
Thomas Mueller committed
927
Drops a role.
Thomas Mueller's avatar
Thomas Mueller committed
928
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
929 930 931 932 933
","
DROP ROLE READONLY
"

"Commands (DDL)","DROP SCHEMA","
934
DROP SCHEMA [ IF EXISTS ] schemaName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
935
","
Thomas Mueller's avatar
Thomas Mueller committed
936
Drops a schema.
937 938
The command will fail if objects in this schema exist and the RESTRICT clause is used (the default).
All objects in this schema are dropped as well if the CASCADE clause is used.
Thomas Mueller's avatar
Thomas Mueller committed
939
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
940 941 942 943 944
","
DROP SCHEMA TEST_SCHEMA
"

"Commands (DDL)","DROP SEQUENCE","
945
DROP SEQUENCE [ IF EXISTS ] sequenceName
Thomas Mueller's avatar
Thomas Mueller committed
946
","
Thomas Mueller's avatar
Thomas Mueller committed
947
Drops a sequence.
Thomas Mueller's avatar
Thomas Mueller committed
948
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
949 950 951 952 953
","
DROP SEQUENCE SEQ_ID
"

"Commands (DDL)","DROP TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
954
DROP TABLE [ IF EXISTS ] tableName [,...] [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
955
","
Thomas Mueller's avatar
Thomas Mueller committed
956
Drops an existing table, or a list of tables.
957 958
The command will fail if dependent objects exist and the RESTRICT clause is used (the default).
All dependent views and constraints are dropped as well if the CASCADE clause is used.
Thomas Mueller's avatar
Thomas Mueller committed
959
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
960 961 962 963 964
","
DROP TABLE TEST
"

"Commands (DDL)","DROP TRIGGER","
965
DROP TRIGGER [ IF EXISTS ] triggerName
Thomas Mueller's avatar
Thomas Mueller committed
966
","
Thomas Mueller's avatar
Thomas Mueller committed
967
Drops an existing trigger.
Thomas Mueller's avatar
Thomas Mueller committed
968
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
969 970 971 972 973
","
DROP TRIGGER TRIG_INS
"

"Commands (DDL)","DROP USER","
974
DROP USER [ IF EXISTS ] userName
Thomas Mueller's avatar
Thomas Mueller committed
975
","
Thomas Mueller's avatar
Thomas Mueller committed
976 977
Drops a user. The current user cannot be dropped.
For compatibility, only unquoted or uppercase user names are allowed.
978

Thomas Mueller's avatar
Thomas Mueller committed
979
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
980
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
981 982 983 984 985
","
DROP USER TOM
"

"Commands (DDL)","DROP VIEW","
986
DROP VIEW [ IF EXISTS ] viewName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
987
","
Thomas Mueller's avatar
Thomas Mueller committed
988 989 990
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.
Thomas Mueller's avatar
Thomas Mueller committed
991
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
992 993 994 995 996
","
DROP VIEW TEST_VIEW
"

"Commands (DDL)","TRUNCATE TABLE","
997
TRUNCATE TABLE tableName [ [ CONTINUE | RESTART ] IDENTITY ]
Thomas Mueller's avatar
Thomas Mueller committed
998
","
999 1000 1001 1002 1003
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).
1004
Linked tables can't be truncated.
1005
If RESTART IDENTITY is specified next values for auto-incremented columns are restarted.
Thomas Mueller's avatar
Thomas Mueller committed
1006

Thomas Mueller's avatar
Thomas Mueller committed
1007
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1008 1009 1010 1011 1012 1013 1014
","
TRUNCATE TABLE TEST
"

"Commands (Other)","CHECKPOINT","
CHECKPOINT
","
Thomas Mueller's avatar
Thomas Mueller committed
1015
Flushes the data to disk.
Thomas Mueller's avatar
Thomas Mueller committed
1016 1017

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1018 1019 1020 1021 1022 1023 1024
","
CHECKPOINT
"

"Commands (Other)","CHECKPOINT SYNC","
CHECKPOINT SYNC
","
Thomas Mueller's avatar
Thomas Mueller committed
1025
Flushes the data to disk and and forces all system buffers be written
Thomas Mueller's avatar
Thomas Mueller committed
1026 1027 1028
to the underlying device.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1029 1030 1031 1032 1033
","
CHECKPOINT SYNC
"

"Commands (Other)","COMMIT","
1034
COMMIT [ WORK ]
Thomas Mueller's avatar
Thomas Mueller committed
1035 1036 1037 1038 1039 1040 1041 1042 1043
","
Commits a transaction.
","
COMMIT
"

"Commands (Other)","COMMIT TRANSACTION","
COMMIT TRANSACTION transactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1044 1045 1046 1047
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.
Thomas Mueller's avatar
Thomas Mueller committed
1048 1049 1050 1051 1052
","
COMMIT TRANSACTION XID_TEST
"

"Commands (Other)","GRANT RIGHT","
1053
GRANT { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
1054 1055
{ { SCHEMA schemaName } | { tableName [,...] } }
TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1056
","
Thomas Mueller's avatar
Thomas Mueller committed
1057 1058 1059
Grants rights for a table to a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1060
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1061 1062 1063 1064
","
GRANT SELECT ON TEST TO READONLY
"

1065 1066 1067 1068 1069 1070
"Commands (Other)","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.
Thomas Mueller's avatar
Thomas Mueller committed
1071
This command commits an open transaction in this connection.
1072 1073 1074 1075
","
GRANT ALTER ANY SCHEMA TO Bob
"

Thomas Mueller's avatar
Thomas Mueller committed
1076
"Commands (Other)","GRANT ROLE","
1077
GRANT roleName TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1078
","
Thomas Mueller's avatar
Thomas Mueller committed
1079 1080 1081
Grants a role to a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1082
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1083 1084 1085 1086 1087
","
GRANT READONLY TO PUBLIC
"

"Commands (Other)","HELP","
1088
HELP [ anything [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
1089 1090 1091 1092 1093 1094 1095 1096 1097
","
Displays the help pages of SQL commands or keywords.
","
HELP SELECT
"

"Commands (Other)","PREPARE COMMIT","
PREPARE COMMIT newTransactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1098 1099
Prepares committing a transaction.
This command is part of the 2-phase-commit protocol.
Thomas Mueller's avatar
Thomas Mueller committed
1100 1101 1102 1103 1104
","
PREPARE COMMIT XID_TEST
"

"Commands (Other)","REVOKE RIGHT","
1105
REVOKE { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
1106 1107
{ { SCHEMA schemaName } | { tableName [,...] } }
FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1108
","
Thomas Mueller's avatar
Thomas Mueller committed
1109 1110 1111
Removes rights for a table from a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1112
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1113 1114 1115 1116 1117
","
REVOKE SELECT ON TEST FROM READONLY
"

"Commands (Other)","REVOKE ROLE","
1118
REVOKE roleName FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1119
","
Thomas Mueller's avatar
Thomas Mueller committed
1120 1121 1122
Removes a role from a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1123
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1124 1125 1126 1127 1128
","
REVOKE READONLY FROM TOM
"

"Commands (Other)","ROLLBACK","
1129
ROLLBACK [ TO SAVEPOINT savepointName ]
Thomas Mueller's avatar
Thomas Mueller committed
1130 1131 1132 1133 1134 1135 1136 1137 1138 1139
","
Rolls back a transaction. If a savepoint name is used, the transaction is only
rolled back to the specified savepoint.
","
ROLLBACK
"

"Commands (Other)","ROLLBACK TRANSACTION","
ROLLBACK TRANSACTION transactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1140 1141 1142 1143
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.
Thomas Mueller's avatar
Thomas Mueller committed
1144 1145 1146 1147 1148 1149 1150
","
ROLLBACK TRANSACTION XID_TEST
"

"Commands (Other)","SAVEPOINT","
SAVEPOINT savepointName
","
Thomas Mueller's avatar
Thomas Mueller committed
1151 1152
Create a new savepoint. See also ROLLBACK.
Savepoints are only valid until the transaction is committed or rolled back.
Thomas Mueller's avatar
Thomas Mueller committed
1153 1154 1155 1156 1157
","
SAVEPOINT HALF_DONE
"

"Commands (Other)","SET @","
1158
SET @variableName [ = ] expression
Thomas Mueller's avatar
Thomas Mueller committed
1159
","
Thomas Mueller's avatar
Thomas Mueller committed
1160
Updates a user-defined variable.
Thomas Mueller's avatar
Thomas Mueller committed
1161
Variables are not persisted and session scoped, that means only visible from within the session in which they are defined.
Thomas Mueller's avatar
Thomas Mueller committed
1162
This command does not commit a transaction, and rollback does not affect it.
Thomas Mueller's avatar
Thomas Mueller committed
1163 1164 1165 1166 1167
","
SET @TOTAL=0
"

"Commands (Other)","SET ALLOW_LITERALS","
1168
SET ALLOW_LITERALS { NONE | ALL | NUMBERS }
Thomas Mueller's avatar
Thomas Mueller committed
1169 1170 1171 1172 1173 1174 1175 1176 1177 1178
","
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).

Thomas Mueller's avatar
Thomas Mueller committed
1179 1180
See also CREATE CONSTANT.

Thomas Mueller's avatar
Thomas Mueller committed
1181
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1182
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1183
This setting is persistent.
1184
This setting can be appended to the database URL: ""jdbc:h2:test;ALLOW_LITERALS=NONE""
Thomas Mueller's avatar
Thomas Mueller committed
1185 1186 1187 1188 1189
","
SET ALLOW_LITERALS NONE
"

"Commands (Other)","SET AUTOCOMMIT","
1190
SET AUTOCOMMIT { TRUE | ON | FALSE | OFF }
Thomas Mueller's avatar
Thomas Mueller committed
1191 1192
","
Switches auto commit on or off.
1193
This setting can be appended to the database URL: ""jdbc:h2:test;AUTOCOMMIT=OFF"" -
1194
however this will not work as expected when using a connection pool
1195 1196
(the connection pool manager will re-enable autocommit when returning
the connection to the pool, so autocommit will only be disabled the first
1197
time the connection is used.
Thomas Mueller's avatar
Thomas Mueller committed
1198 1199 1200 1201 1202 1203 1204
","
SET AUTOCOMMIT OFF
"

"Commands (Other)","SET CACHE_SIZE","
SET CACHE_SIZE int
","
1205
Sets the size of the cache in KB (each KB being 1024 bytes) for the current database.
1206 1207
The default is 65536 per available GB of RAM, i.e. 64 MB per GB.
The value is rounded to the next higher power of two.
Thomas Mueller's avatar
Thomas Mueller committed
1208 1209
Depending on the virtual machine, the actual memory required may be higher.

Thomas Mueller's avatar
Thomas Mueller committed
1210
This setting is persistent and affects all connections as there is only one cache per database.
Thomas Mueller's avatar
Thomas Mueller committed
1211
Using a very small value (specially 0) will reduce performance a lot.
Thomas Mueller's avatar
Thomas Mueller committed
1212 1213
This setting only affects the database engine (the server in a client/server environment;
in embedded mode, the database engine is in the same process as the application).
Thomas Mueller's avatar
Thomas Mueller committed
1214
It has no effect for in-memory databases.
1215

Thomas Mueller's avatar
Thomas Mueller committed
1216
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1217
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1218
This setting is persistent.
1219
This setting can be appended to the database URL: ""jdbc:h2:test;CACHE_SIZE=8192""
Thomas Mueller's avatar
Thomas Mueller committed
1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231
","
SET CACHE_SIZE 8192
"

"Commands (Other)","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
Thomas Mueller's avatar
Thomas Mueller committed
1232 1233
server is not responding).

Thomas Mueller's avatar
Thomas Mueller committed
1234
This command is effective immediately, but does not commit an open transaction.
Thomas Mueller's avatar
Thomas Mueller committed
1235 1236 1237 1238
","
SET CLUSTER ''
"

1239 1240 1241 1242
"Commands (Other)","SET BINARY_COLLATION","
SET BINARY_COLLATION
{ UNSIGNED | SIGNED } ] }
","
Thomas Mueller's avatar
Thomas Mueller committed
1243 1244
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.
1245 1246 1247
This command can only be executed if there are no tables defined.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1248
This command commits an open transaction in this connection.
1249 1250 1251 1252 1253
This setting is persistent.
","
SET BINARY_COLLATION SIGNED
"

1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266
"Commands (Other)","SET BUILTIN_ALIAS_OVERRIDE","
SET BUILTIN_ALIAS_OVERRIDE
{ TRUE | FALSE } ] }
","
Allows the overriding of the builtin system date/time functions
for unit testing purposes.

Admin rights are required to execute this command.
This command commits an open transaction in this connection.
","
SET BUILTIN_ALIAS_OVERRIDE TRUE
"

Thomas Mueller's avatar
Thomas Mueller committed
1267
"Commands (Other)","SET COLLATION","
1268
SET [ DATABASE ] COLLATION
1269 1270
{ OFF | collationName
    [ STRENGTH { PRIMARY | SECONDARY | TERTIARY | IDENTICAL } ] }
Thomas Mueller's avatar
Thomas Mueller committed
1271
","
Thomas Mueller's avatar
Thomas Mueller committed
1272 1273
Sets the collation used for comparing strings.
This command can only be executed if there are no tables defined.
Thomas Mueller's avatar
Thomas Mueller committed
1274 1275
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;
Thomas Mueller's avatar
Thomas Mueller committed
1276
TERTIARY is both case- and umlaut-sensitive; IDENTICAL is sensitive to all differences and only affects ordering).
Thomas Mueller's avatar
Thomas Mueller committed
1277

1278 1279 1280 1281 1282
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).
1283 1284
The charset collator is used if the collation name starts with CHARSET_ (e.g. CHARSET_CP500). This collator sorts
strings according to the binary representation in the given charset.
1285

Thomas Mueller's avatar
Thomas Mueller committed
1286
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1287
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1288
This setting is persistent.
1289
This setting can be appended to the database URL: ""jdbc:h2:test;COLLATION='ENGLISH'""
Thomas Mueller's avatar
Thomas Mueller committed
1290 1291
","
SET COLLATION ENGLISH
1292
SET COLLATION CHARSET_CP500
Thomas Mueller's avatar
Thomas Mueller committed
1293 1294 1295
"

"Commands (Other)","SET COMPRESS_LOB","
1296
SET COMPRESS_LOB { NO | LZF | DEFLATE }
Thomas Mueller's avatar
Thomas Mueller committed
1297
","
Thomas Mueller's avatar
Thomas Mueller committed
1298 1299 1300 1301
This feature is only available for the PageStore storage engine.
For the MVStore engine (the default for H2 version 1.4.x),
append "";COMPRESS=TRUE"" to the database URL instead.

Thomas Mueller's avatar
Thomas Mueller committed
1302 1303
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.
Thomas Mueller's avatar
Thomas Mueller committed
1304

Thomas Mueller's avatar
Thomas Mueller committed
1305
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1306
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1307
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1308 1309 1310 1311 1312 1313 1314 1315
","
SET COMPRESS_LOB LZF
"

"Commands (Other)","SET DATABASE_EVENT_LISTENER","
SET DATABASE_EVENT_LISTENER classNameString
","
Sets the event listener class. An empty string ('') means no listener should be
Thomas Mueller's avatar
Thomas Mueller committed
1316 1317 1318 1319
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).
1320
This setting can be appended to the database URL: ""jdbc:h2:test;DATABASE_EVENT_LISTENER='sample.MyListener'""
Thomas Mueller's avatar
Thomas Mueller committed
1321 1322 1323 1324 1325 1326 1327
","
SET DATABASE_EVENT_LISTENER 'sample.MyListener'
"

"Commands (Other)","SET DB_CLOSE_DELAY","
SET DB_CLOSE_DELAY int
","
Thomas Mueller's avatar
Thomas Mueller committed
1328 1329
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.
Thomas Mueller's avatar
Thomas Mueller committed
1330 1331 1332 1333
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.
Thomas Mueller's avatar
Thomas Mueller committed
1334

Thomas Mueller's avatar
Thomas Mueller committed
1335
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1336
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1337
This setting is persistent.
1338
This setting can be appended to the database URL: ""jdbc:h2:test;DB_CLOSE_DELAY=-1""
Thomas Mueller's avatar
Thomas Mueller committed
1339 1340 1341 1342 1343 1344 1345 1346
","
SET DB_CLOSE_DELAY -1
"

"Commands (Other)","SET DEFAULT_LOCK_TIMEOUT","
SET DEFAULT LOCK_TIMEOUT int
","
Sets the default lock timeout (in milliseconds) in this database that is used
Thomas Mueller's avatar
Thomas Mueller committed
1347 1348
for the new sessions. The default value for this setting is 1000 (one second).

Thomas Mueller's avatar
Thomas Mueller committed
1349
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1350
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1351
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1352 1353 1354 1355 1356
","
SET DEFAULT_LOCK_TIMEOUT 5000
"

"Commands (Other)","SET DEFAULT_TABLE_TYPE","
1357
SET DEFAULT_TABLE_TYPE { MEMORY | CACHED }
Thomas Mueller's avatar
Thomas Mueller committed
1358 1359 1360
","
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
Thomas Mueller's avatar
Thomas Mueller committed
1361
the data is still stored in the database file. The size of memory tables is
Thomas Mueller's avatar
Thomas Mueller committed
1362
limited by the memory. The default is CACHED.
Thomas Mueller's avatar
Thomas Mueller committed
1363

Thomas Mueller's avatar
Thomas Mueller committed
1364
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1365
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1366
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1367
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1368 1369 1370 1371 1372
","
SET DEFAULT_TABLE_TYPE MEMORY
"

"Commands (Other)","SET EXCLUSIVE","
Thomas Mueller's avatar
Thomas Mueller committed
1373
SET EXCLUSIVE { 0 | 1 | 2 }
Thomas Mueller's avatar
Thomas Mueller committed
1374
","
Thomas Mueller's avatar
Thomas Mueller committed
1375 1376 1377 1378 1379 1380 1381 1382 1383 1384
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.
Thomas Mueller's avatar
Thomas Mueller committed
1385 1386

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1387
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1388
","
Thomas Mueller's avatar
Thomas Mueller committed
1389
SET EXCLUSIVE 1
Thomas Mueller's avatar
Thomas Mueller committed
1390 1391 1392
"

"Commands (Other)","SET IGNORECASE","
1393
SET IGNORECASE { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
1394 1395 1396 1397 1398
","
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.
Thomas Mueller's avatar
Thomas Mueller committed
1399
String literals and parameters are however still considered case sensitive even if this option is set.
Thomas Mueller's avatar
Thomas Mueller committed
1400

Thomas Mueller's avatar
Thomas Mueller committed
1401
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1402
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1403
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1404
This setting can be appended to the database URL: ""jdbc:h2:test;IGNORECASE=TRUE""
Thomas Mueller's avatar
Thomas Mueller committed
1405 1406 1407 1408
","
SET IGNORECASE TRUE
"

1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420
"Commands (Other)","SET JAVA_OBJECT_SERIALIZER","
SET JAVA_OBJECT_SERIALIZER
{ null | className }
","
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.
Thomas Mueller's avatar
Thomas Mueller committed
1421
This command commits an open transaction in this connection.
1422 1423 1424 1425 1426 1427 1428
This setting is persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;JAVA_OBJECT_SERIALIZER='com.acme.SerializerClassName'""
","
SET JAVA_OBJECT_SERIALIZER 'com.acme.SerializerClassName'
"


1429 1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442 1443 1444 1445
"Commands (Other)","SET LAZY_QUERY_EXECUTION","
SET LAZY_QUERY_EXECUTION int
","
Sets the lazy query execution mode. The values 0, 1 are supported.

If true, then large results are retrieved in chunks.

Note that not all queries support this feature, queries which do not are processed normally.

Admin rights are required to execute this command, as it affects all connections.
This command commits an open transaction in this connection.
This setting is not persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;LAZY_QUERY_EXECUTION=1""
","
SET LAZY_QUERY_EXECUTION 1
"

1446
"Commands (Other)","SET LOG","
1447
SET LOG int
1448 1449 1450 1451
","
Sets the transaction log mode. The values 0, 1, and 2 are supported, the default is 2.
This setting affects all connections.

1452
LOG 0 means the transaction log is disabled completely. It is the fastest mode,
1453 1454 1455 1456
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.

1457 1458
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
1459 1460
against power failure is required, but the data must be protected against killing the process.

1461 1462
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
1463 1464
file system, this will also protect against power failure in the majority if cases.

Thomas Mueller's avatar
Thomas Mueller committed
1465
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1466
This command commits an open transaction in this connection.
1467
This setting is not persistent.
1468
This setting can be appended to the database URL: ""jdbc:h2:test;LOG=0""
1469 1470 1471 1472
","
SET LOG 1
"

Thomas Mueller's avatar
Thomas Mueller committed
1473 1474 1475 1476
"Commands (Other)","SET LOCK_MODE","
SET LOCK_MODE int
","
Sets the lock mode. The values 0, 1, 2, and 3 are supported. The default is 3
1477
(READ_COMMITTED). This setting affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1478 1479 1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490

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).

Thomas Mueller's avatar
Thomas Mueller committed
1491
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1492
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1493
This setting is persistent.
1494
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_MODE=3""
Thomas Mueller's avatar
Thomas Mueller committed
1495 1496 1497 1498 1499 1500 1501 1502
","
SET LOCK_MODE 1
"

"Commands (Other)","SET LOCK_TIMEOUT","
SET LOCK_TIMEOUT int
","
Sets the lock timeout (in milliseconds) for the current session. The default
Thomas Mueller's avatar
Thomas Mueller committed
1503 1504 1505
value for this setting is 1000 (one second).

This command does not commit a transaction, and rollback does not affect it.
1506
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_TIMEOUT=10000""
Thomas Mueller's avatar
Thomas Mueller committed
1507 1508 1509 1510 1511 1512 1513
","
SET LOCK_TIMEOUT 1000
"

"Commands (Other)","SET MAX_LENGTH_INPLACE_LOB","
SET MAX_LENGTH_INPLACE_LOB int
","
Thomas Mueller's avatar
Thomas Mueller committed
1514
Sets the maximum size of an in-place LOB object.
1515

1516
This is the maximum length of an LOB that is stored with the record itself,
1517 1518
and the default value is 128.

Thomas Mueller's avatar
Thomas Mueller committed
1519
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1520
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1521
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1522 1523 1524 1525 1526 1527 1528
","
SET MAX_LENGTH_INPLACE_LOB 128
"

"Commands (Other)","SET MAX_LOG_SIZE","
SET MAX_LOG_SIZE int
","
Thomas Mueller's avatar
Thomas Mueller committed
1529 1530
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.
noelgrandin's avatar
noelgrandin committed
1531
If there is an open transaction, the transaction log will continue to grow however.
Thomas Mueller's avatar
Thomas Mueller committed
1532
The default max size is 16 MB.
Thomas Mueller's avatar
Thomas Mueller committed
1533
This setting has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1534

Thomas Mueller's avatar
Thomas Mueller committed
1535
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1536
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1537
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1538 1539 1540 1541 1542 1543 1544 1545
","
SET MAX_LOG_SIZE 2
"

"Commands (Other)","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
1546
are read, then the rows are buffered to disk.
1547
The default is 40000 per GB of available RAM.
Thomas Mueller's avatar
Thomas Mueller committed
1548

Thomas Mueller's avatar
Thomas Mueller committed
1549
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1550
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1551
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1552
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1553 1554 1555 1556 1557 1558 1559
","
SET MAX_MEMORY_ROWS 1000
"

"Commands (Other)","SET MAX_MEMORY_UNDO","
SET MAX_MEMORY_UNDO int
","
1560
The maximum number of undo records per a session that are kept in-memory.
Thomas Mueller's avatar
Thomas Mueller committed
1561 1562
If a transaction is larger, the records are buffered to disk.
The default value is 50000.
Thomas Mueller's avatar
Thomas Mueller committed
1563
Changes to tables without a primary key can not be buffered to disk.
Thomas Mueller's avatar
Thomas Mueller committed
1564 1565
This setting is not supported when using multi-version concurrency.

Thomas Mueller's avatar
Thomas Mueller committed
1566
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1567
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1568
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1569
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1570 1571 1572 1573 1574 1575 1576 1577 1578
","
SET MAX_MEMORY_UNDO 1000
"

"Commands (Other)","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
Thomas Mueller's avatar
Thomas Mueller committed
1579 1580 1581
operation. The default max size is 100000. 0 means no limit.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1582
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1583
It has no effect for in-memory databases.
1584
This setting can be appended to the database URL: ""jdbc:h2:test;MAX_OPERATION_MEMORY=10000""
Thomas Mueller's avatar
Thomas Mueller committed
1585 1586 1587 1588 1589
","
SET MAX_OPERATION_MEMORY 0
"

"Commands (Other)","SET MODE","
1590
SET MODE { REGULAR | DB2 | DERBY | HSQLDB | MSSQLSERVER | MYSQL | ORACLE | POSTGRESQL }
Thomas Mueller's avatar
Thomas Mueller committed
1591 1592
","
Changes to another database compatibility mode. For details, see Compatibility
Thomas Mueller's avatar
Thomas Mueller committed
1593 1594 1595
Modes in the feature section.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1596
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1597
This command commits an open transaction in this connection.
1598
This setting can be appended to the database URL: ""jdbc:h2:test;MODE=MYSQL""
Thomas Mueller's avatar
Thomas Mueller committed
1599 1600 1601 1602 1603
","
SET MODE HSQLDB
"

"Commands (Other)","SET MULTI_THREADED","
1604
SET MULTI_THREADED { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1605
","
1606 1607 1608
Enabled (1) or disabled (0) multi-threading inside the database engine.
MULTI_THREADED is enabled by default with default MVStore storage engine.
MULTI_THREADED is disabled by default when using PageStore storage engine, enabling this with PageStore is experimental only.
Thomas Mueller's avatar
Thomas Mueller committed
1609 1610 1611 1612

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.

Thomas Mueller's avatar
Thomas Mueller committed
1613
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1614
This command commits an open transaction in this connection.
1615
This setting can be appended to the database URL: ""jdbc:h2:test;MULTI_THREADED=1""
Thomas Mueller's avatar
Thomas Mueller committed
1616 1617 1618 1619 1620
","
SET MULTI_THREADED 1
"

"Commands (Other)","SET OPTIMIZE_REUSE_RESULTS","
1621
SET OPTIMIZE_REUSE_RESULTS { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1622 1623 1624
","
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
Thomas Mueller's avatar
Thomas Mueller committed
1625 1626
the tables was changed. This option is enabled by default.

Thomas Mueller's avatar
Thomas Mueller committed
1627
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1628
This command commits an open transaction in this connection.
1629
This setting can be appended to the database URL: ""jdbc:h2:test;OPTIMIZE_REUSE_RESULTS=0""
Thomas Mueller's avatar
Thomas Mueller committed
1630 1631 1632 1633 1634 1635 1636 1637 1638
","
SET OPTIMIZE_REUSE_RESULTS 0
"

"Commands (Other)","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.
Thomas Mueller's avatar
Thomas Mueller committed
1639

Thomas Mueller's avatar
Thomas Mueller committed
1640
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1641 1642 1643 1644
","
SET PASSWORD 'abcstzri!.5'
"

1645 1646 1647 1648 1649 1650 1651
"Commands (Other)","SET QUERY_STATISTICS","
SET QUERY_STATISTICS { TRUE | FALSE }
","
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.
Thomas Mueller's avatar
Thomas Mueller committed
1652
This command commits an open transaction in this connection.
1653 1654 1655 1656 1657
Admin rights are required to execute this command, as it affects all connections.
","
SET QUERY_STATISTICS FALSE
"

1658 1659 1660 1661 1662 1663 1664 1665 1666 1667 1668 1669 1670
"Commands (Other)","SET QUERY_STATISTICS_MAX_ENTRIES","
SET QUERY_STATISTICS int
","
Set the maximum number of entries in query statistics meta-table.
Default value is 100.

This setting is not persistent.
This command commits an open transaction in this connection.
Admin rights are required to execute this command, as it affects all connections.
","
SET QUERY_STATISTICS_MAX_ENTRIES 500
"

Thomas Mueller's avatar
Thomas Mueller committed
1671 1672 1673 1674 1675
"Commands (Other)","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
Thomas Mueller's avatar
Thomas Mueller committed
1676 1677 1678
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.
Thomas Mueller's avatar
Thomas Mueller committed
1679 1680 1681 1682 1683
","
SET QUERY_TIMEOUT 10000
"

"Commands (Other)","SET REFERENTIAL_INTEGRITY","
1684
SET REFERENTIAL_INTEGRITY { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
1685 1686 1687
","
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
Thomas Mueller's avatar
Thomas Mueller committed
1688 1689 1690
for one table.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1691
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1692
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1693 1694 1695 1696
","
SET REFERENTIAL_INTEGRITY FALSE
"

1697 1698 1699 1700 1701 1702
"Commands (Other)","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.
1703 1704 1705
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,
1706 1707 1708 1709
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.
Thomas Mueller's avatar
Thomas Mueller committed
1710
This command commits an open transaction in this connection.
1711 1712 1713 1714 1715 1716
This setting is persistent.
This setting can be appended to the database URL: ""jdbc:h2:test;RETENTION_TIME=0""
","
SET RETENTION_TIME 0
"

Thomas Mueller's avatar
Thomas Mueller committed
1717 1718 1719 1720 1721
"Commands (Other)","SET SALT HASH","
SET SALT bytes HASH bytes
","
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.
Thomas Mueller's avatar
Thomas Mueller committed
1722

Thomas Mueller's avatar
Thomas Mueller committed
1723
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1724 1725 1726 1727 1728 1729 1730 1731 1732
","
SET SALT '00' HASH '1122'
"

"Commands (Other)","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
Thomas Mueller's avatar
Thomas Mueller committed
1733 1734 1735
connections is PUBLIC.

This command does not commit a transaction, and rollback does not affect it.
1736
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA=ABC""
Thomas Mueller's avatar
Thomas Mueller committed
1737 1738 1739 1740 1741 1742 1743 1744 1745
","
SET SCHEMA INFORMATION_SCHEMA
"

"Commands (Other)","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
Thomas Mueller's avatar
Thomas Mueller committed
1746 1747 1748
connections is PUBLIC.

This command does not commit a transaction, and rollback does not affect it.
1749
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA_SEARCH_PATH=ABC,DEF""
Thomas Mueller's avatar
Thomas Mueller committed
1750 1751 1752 1753 1754 1755 1756 1757 1758
","
SET SCHEMA_SEARCH_PATH INFORMATION_SCHEMA, PUBLIC
"

"Commands (Other)","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
Thomas Mueller's avatar
Thomas Mueller committed
1759 1760 1761
disabled).

This command does not commit a transaction, and rollback does not affect it.
1762
This setting can be appended to the database URL: ""jdbc:h2:test;THROTTLE=50""
Thomas Mueller's avatar
Thomas Mueller committed
1763 1764 1765 1766 1767
","
SET THROTTLE 200
"

"Commands (Other)","SET TRACE_LEVEL","
1768
SET { TRACE_LEVEL_FILE | TRACE_LEVEL_SYSTEM_OUT } int
Thomas Mueller's avatar
Thomas Mueller committed
1769 1770 1771
","
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.
1772
To use SLF4J, append "";TRACE_LEVEL_FILE=4"" to the database URL when opening the database.
Thomas Mueller's avatar
Thomas Mueller committed
1773

Thomas Mueller's avatar
Thomas Mueller committed
1774
This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1775
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1776
This command does not commit a transaction, and rollback does not affect it.
1777
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_LEVEL_SYSTEM_OUT=3""
Thomas Mueller's avatar
Thomas Mueller committed
1778 1779 1780 1781 1782 1783 1784 1785 1786 1787 1788
","
SET TRACE_LEVEL_SYSTEM_OUT 3
"

"Commands (Other)","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.

Thomas Mueller's avatar
Thomas Mueller committed
1789
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1790
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1791
This command commits an open transaction in this connection.
1792
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_MAX_FILE_SIZE=3""
Thomas Mueller's avatar
Thomas Mueller committed
1793 1794 1795 1796 1797 1798 1799 1800 1801 1802
","
SET TRACE_MAX_FILE_SIZE 10
"

"Commands (Other)","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.
Thomas Mueller's avatar
Thomas Mueller committed
1803

Thomas Mueller's avatar
Thomas Mueller committed
1804
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1805 1806 1807 1808 1809 1810 1811 1812
","
SET UNDO_LOG 0
"

"Commands (Other)","SET WRITE_DELAY","
SET WRITE_DELAY int
","
Set the maximum delay between a commit and flushing the log, in milliseconds.
Thomas Mueller's avatar
Thomas Mueller committed
1813 1814
This setting is persistent. The default is 500 ms.

Thomas Mueller's avatar
Thomas Mueller committed
1815
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1816
This command commits an open transaction in this connection.
1817
This setting can be appended to the database URL: ""jdbc:h2:test;WRITE_DELAY=0""
Thomas Mueller's avatar
Thomas Mueller committed
1818 1819 1820 1821 1822
","
SET WRITE_DELAY 2000
"

"Commands (Other)","SHUTDOWN","
1823
SHUTDOWN [ IMMEDIATELY | COMPACT | DEFRAG ]
Thomas Mueller's avatar
Thomas Mueller committed
1824
","
1825 1826
This statement closes all open connections to the database and closes the
database. This command is usually not required, as the database is
Thomas Mueller's avatar
Thomas Mueller committed
1827
closed automatically when the last connection to it is closed.
Thomas Mueller's avatar
Thomas Mueller committed
1828

1829 1830
If no option is used, then the database is closed normally.
All connections are closed, open transactions are rolled back.
Thomas Mueller's avatar
Thomas Mueller committed
1831 1832 1833

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,
1834
but only for at most the time defined by the database setting ""h2.maxCompactTime"" in milliseconds (see there).
Thomas Mueller's avatar
Thomas Mueller committed
1835 1836

SHUTDOWN IMMEDIATELY closes the database files without any cleanup and without compacting.
Thomas Mueller's avatar
Thomas Mueller committed
1837

1838
SHUTDOWN DEFRAG re-orders the pages when closing the database so that table scans are faster. In case of MVStore it is currently equivalent to COMPACT.
1839

Thomas Mueller's avatar
Thomas Mueller committed
1840
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1841
","
1842
SHUTDOWN COMPACT
Thomas Mueller's avatar
Thomas Mueller committed
1843 1844
"

1845 1846 1847 1848 1849 1850 1851 1852 1853 1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867 1868 1869 1870 1871 1872 1873 1874 1875 1876 1877 1878 1879 1880 1881 1882 1883 1884 1885 1886 1887 1888 1889 1890 1891 1892 1893 1894 1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905 1906 1907 1908 1909 1910 1911 1912 1913 1914 1915 1916 1917 1918 1919 1920 1921 1922 1923 1924 1925 1926 1927 1928 1929 1930 1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955 1956 1957 1958 1959 1960 1961 1962 1963 1964 1965 1966 1967 1968 1969 1970 1971 1972 1973 1974 1975 1976
"Datetime fields","Datetime field","
yearField | monthField | dayOfMonthField
    | hourField | minuteField | secondField
    | millisecondField | microsecondField | nanosecondField
    | timezoneHourField | timezoneMinuteField
    | dayOfWeekField | isoDayOfWeekField
    | weekOfYearField | isoWeekOfYearField
    | quarterField | dayOfYearField | epochField
","
Fields for EXTRACT, DATEADD, and DATEDIFF functions.
","
YEAR
"

"Datetime fields","Year field","
YEAR | YYYY | YY | SQL_TSI_YEAR
","
Year.
","
YEAR
"

"Datetime fields","Month field","
MONTH | MM | M | SQL_TSI_MONTH
","
Month (1-12).
","
MONTH
"

"Datetime fields","Day of month field","
DAY | DD | D | SQL_TSI_DAY
","
Day of month (1-31).
","
DAY
"

"Datetime fields","Hour field","
HOUR | HH | SQL_TSI_HOUR
","
Hour (0-23).
","
HOUR
"

"Datetime fields","Minute field","
MINUTE | MI | N | SQL_TSI_MINUTE
","
Minute (0-59).
","
MINUTE
"

"Datetime fields","Second field","
SECOND | SS | S | SQL_TSI_SECOND
","
Second (0-59).
","
SECOND
"

"Datetime fields","Millisecond field","
MILLISECOND | MS
","
Millisecond (0-999).
","
MILLISECOND
"

"Datetime fields","Microsecond field","
MICROSECOND | MCS
","
Microsecond (0-999999).
","
MICROSECOND
"

"Datetime fields","Nanosecond field","
NANOSECOND | NS
","
Nanosecond (0-999999999).
","
NANOSECOND
"

"Datetime fields","Timezone hour field","
TIMEZONE_HOUR
","
Timezone hour (from -18 to +18).
","
TIMEZONE_HOUR
"

"Datetime fields","Timezone minute field","
TIMEZONE_MINUTE
","
Timezone minute (from -59 to +59).
","
TIMEZONE_MINUTE
"

"Datetime fields","Day of week field","
DAY_OF_WEEK | DAYOFWEEK | DOW
","
Day of week (1-7). Sunday is 1.
","
DAY_OF_WEEK
"

"Datetime fields","ISO day of week field","
ISO_DAY_OF_WEEK
","
ISO day of week (1-7). Monday is 1.
","
ISO_DAY_OF_WEEK
"

"Datetime fields","Week of year field","
WEEK | WW | W | SQL_TSI_WEEK
","
Week of year (1-53).
EXTRACT function uses local rules to get number of week in year.
DATEDIFF function uses Sunday as a first day of week.
","
WEEK
"

"Datetime fields","ISO week of year field","
ISO_WEEK
","
ISO week of year (1-53).
1977 1978
ISO definition is used when first week of year should have at least four days
and week is started with Monday.
1979 1980 1981 1982 1983 1984 1985 1986 1987 1988 1989 1990 1991 1992 1993 1994 1995 1996 1997 1998 1999 2000 2001 2002 2003 2004 2005 2006 2007 2008 2009
","
ISO_WEEK
"

"Datetime fields","Quarter field","
QUARTER
","
Quarter (1-4).
","
QUARTER
"

"Datetime fields","Day of year field","
DAYOFYEAR | DAY_OF_YEAR | DOY | DY
","
Day of year (1-366).
","
DAYOFYEAR
"

"Datetime fields","Epoch field","
EPOCH
","
For TIMESTAMP values number of seconds since 1970-01-01 00:00:00 in local time zone.
For TIMESTAMP WITH TIME ZONE values number of seconds since 1970-01-01 00:00:00 in UTC time zone.
For DATE values number of seconds since 1970-01-01.
For TIME values number of seconds since midnight.
","
EPOCH
"

2010 2011
"Other Grammar","Alias","
name
Thomas Mueller's avatar
Thomas Mueller committed
2012
","
2013
An alias is a name that is only valid in the context of the statement.
Thomas Mueller's avatar
Thomas Mueller committed
2014
","
2015
A
Thomas Mueller's avatar
Thomas Mueller committed
2016 2017
"

2018 2019
"Other Grammar","And Condition","
condition [ { AND condition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2020
","
2021
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2022
","
2023
ID=1 AND NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2024 2025
"

2026
"Other Grammar","Array","
2027
( [ expression, [ expression [,...] ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
2028
","
2029 2030
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.
Thomas Mueller's avatar
Thomas Mueller committed
2031
","
2032
(1, 2)
2033 2034
(1, )
()
Thomas Mueller's avatar
Thomas Mueller committed
2035 2036
"

2037 2038
"Other Grammar","Boolean","
TRUE | FALSE
2039
","
2040
A boolean value.
2041
","
2042
TRUE
2043 2044
"

2045 2046
"Other Grammar","Bytes","
X'hex'
Thomas Mueller's avatar
Thomas Mueller committed
2047
","
2048
A binary value. The hex value is not case sensitive.
Thomas Mueller's avatar
Thomas Mueller committed
2049
","
2050
X'01FF'
Thomas Mueller's avatar
Thomas Mueller committed
2051 2052
"

2053 2054 2055
"Other Grammar","Case","
CASE expression { WHEN expression THEN expression } [...]
[ ELSE expression ] END
Thomas Mueller's avatar
Thomas Mueller committed
2056
","
2057 2058
Returns the first expression where the value is equal to the test expression. If
no else part is specified, return NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2059
","
2060
CASE CNT WHEN 0 THEN 'No' WHEN 1 THEN 'One' ELSE 'Some' END
Thomas Mueller's avatar
Thomas Mueller committed
2061 2062
"

2063 2064 2065
"Other Grammar","Case When","
CASE { WHEN expression THEN expression} [...]
[ ELSE expression ] END
Thomas Mueller's avatar
Thomas Mueller committed
2066
","
2067 2068
Returns the first expression where the condition is true. If no else part is
specified, return NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2069
","
2070 2071 2072 2073
CASE WHEN CNT<10 THEN 'Low' ELSE 'High' END
"

"Other Grammar","Cipher","
2074
AES
2075
","
2076
Only the algorithm AES (""AES-128"") is supported currently.
2077 2078
","
AES
Thomas Mueller's avatar
Thomas Mueller committed
2079 2080
"

2081
"Other Grammar","Column Definition","
2082
dataType [ VISIBLE | INVISIBLE ]
2083 2084 2085
[ { DEFAULT expression
    | AS computedColumnExpression
    | GENERATED {ALWAYS | BY DEFAULT} AS IDENTITY [(sequenceOptions)]} ]
2086
[ ON UPDATE expression ] [ [ NOT ] NULL ]
2087
[ { AUTO_INCREMENT | IDENTITY } [ ( startInt [, incrementInt ] ) ] ]
Thomas Mueller's avatar
Thomas Mueller committed
2088 2089
[ SELECTIVITY selectivity ] [ COMMENT expression ]
[ PRIMARY KEY [ HASH ] | UNIQUE ] [ CHECK condition ]
2090 2091
","
Default expressions are used if no explicit value was used when adding a row.
Thomas Mueller's avatar
Thomas Mueller committed
2092
The computed column expression is evaluated and assigned whenever the row changes.
2093 2094 2095
On update column expression is used if row is updated,
at least one column have a new value that is different from its previous value
and value for this column is not set explicitly in update statement.
2096

2097 2098 2099 2100 2101
Identity, auto-increment, or generated as identity columns are columns with a sequence as the default.
The column declared as the identity columns with IDENTITY data type or with IDENTITY () clause
is implicitly the primary key column of this table.
AUTO_INCREMENT and GENERATED clauses do not create the primary key constraint.
GENERATED ALWAYS is accepted by treated in the same way as GENERATED BY DEFAULT.
Thomas Mueller's avatar
Thomas Mueller committed
2102

2103 2104 2105
The invisible column will not be displayed as a result of SELECT * query.
Otherwise, it works as normal column.

Thomas Mueller's avatar
Thomas Mueller committed
2106 2107
The options PRIMARY KEY, UNIQUE, and CHECK are not supported for ALTER statements.

Thomas Mueller's avatar
Thomas Mueller committed
2108 2109
Check constraints can reference columns of the table,
and they can reference objects that exist while the statement is executed.
Thomas Mueller's avatar
Thomas Mueller committed
2110 2111
Conditions are only checked when a row is added or modified
in the table where the constraint exists.
2112

2113
","
Thomas Mueller's avatar
Thomas Mueller committed
2114 2115 2116
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);
2117 2118
"

2119 2120
"Other Grammar","Comments","
-- anythingUntilEndOfLine | // anythingUntilEndOfLine | /* anythingUntilEndComment */
Thomas Mueller's avatar
Thomas Mueller committed
2121
","
2122 2123 2124
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.
Thomas Mueller's avatar
Thomas Mueller committed
2125
","
2126
// This is a comment
Thomas Mueller's avatar
Thomas Mueller committed
2127 2128
"

2129
"Other Grammar","Compare","
2130
<> | <= | >= | = | < | > | != | &&
Thomas Mueller's avatar
Thomas Mueller committed
2131
","
2132
Comparison operator. The operator != is the same as <>.
2133
The operator ""&&"" means overlapping; it can only be used with geometry types.
Thomas Mueller's avatar
Thomas Mueller committed
2134
","
2135
<>
Thomas Mueller's avatar
Thomas Mueller committed
2136 2137 2138
"

"Other Grammar","Condition","
2139
operand [ conditionRightHandSide ] | NOT condition | EXISTS ( select )
Thomas Mueller's avatar
Thomas Mueller committed
2140 2141 2142 2143 2144 2145 2146
","
Boolean value or condition.
","
ID<>2
"

"Other Grammar","Condition Right Hand Side","
2147 2148
compare { { { ALL | ANY | SOME } ( select ) } | operand }
    | IS [ NOT ] NULL
2149
    | IS [ NOT ] [ DISTINCT FROM ] operand
2150 2151
    | BETWEEN operand AND operand
    | IN ( { select | expression [,...] } )
2152
    | [ NOT ] [ LIKE | ILIKE ] operand [ ESCAPE string ]
2153
    | [ NOT ] REGEXP operand
Thomas Mueller's avatar
Thomas Mueller committed
2154
","
Thomas Mueller's avatar
Thomas Mueller committed
2155
The right hand side of a condition.
2156

Thomas Mueller's avatar
Thomas Mueller committed
2157
The conditions ""IS [ NOT ]"" and ""IS [ NOT ] DISTINCT FROM"" are null-safe, meaning
2158 2159
NULL is considered the same as NULL, and the condition never evaluates to NULL.

Thomas Mueller's avatar
Thomas Mueller committed
2160 2161 2162 2163 2164
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).
2165 2166 2167
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.
2168

2169 2170
ILIKE does a case-insensitive compare.

Thomas Mueller's avatar
Thomas Mueller committed
2171
When comparing with REGEXP, regular expression matching is used.
2172
See Java ""Matcher.find"" for details.
Thomas Mueller's avatar
Thomas Mueller committed
2173 2174 2175 2176
","
LIKE 'Jo%'
"

2177
"Other Grammar","Constraint","
Thomas Mueller's avatar
Thomas Mueller committed
2178 2179 2180 2181 2182
[ constraintNameDefinition ]
{ CHECK expression
    | UNIQUE ( columnName [,...] )
    | referentialConstraint
    | PRIMARY KEY [ HASH ] ( columnName [,...] ) }
Thomas Mueller's avatar
Thomas Mueller committed
2183
","
Thomas Mueller's avatar
Thomas Mueller committed
2184 2185
Defines a constraint.
The check condition must evaluate to TRUE, FALSE or NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2186
TRUE and NULL mean the operation is to be permitted,
Thomas Mueller's avatar
Thomas Mueller committed
2187 2188
and FALSE means the operation is to be rejected.
To prevent NULL in a column, use NOT NULL instead of a check constraint.
Thomas Mueller's avatar
Thomas Mueller committed
2189
","
2190
PRIMARY KEY(ID, NAME)
Thomas Mueller's avatar
Thomas Mueller committed
2191 2192
"

2193 2194
"Other Grammar","Constraint Name Definition","
CONSTRAINT [ IF NOT EXISTS ] newConstraintName
Thomas Mueller's avatar
Thomas Mueller committed
2195
","
2196
Defines a constraint name.
Thomas Mueller's avatar
Thomas Mueller committed
2197
","
2198
CONSTRAINT CONST_ID
Thomas Mueller's avatar
Thomas Mueller committed
2199 2200
"

2201 2202
"Other Grammar","Csv Options","
charsetString [, fieldSepString [, fieldDelimString [, escString [, nullString]]]]]
2203
    | optionString
Thomas Mueller's avatar
Thomas Mueller committed
2204
","
2205
Optional parameters for CSVREAD and CSVWRITE.
2206 2207
Instead of setting the options one by one, all options can be
combined into a space separated key-value pairs, as follows:
Thomas Mueller's avatar
Thomas Mueller committed
2208 2209
""STRINGDECODE('charset=UTF-8 escape=\"" fieldDelimiter=\"" fieldSeparator=, ' ||""
""'lineComment=# lineSeparator=\n null= rowSeparator=')"".
2210
The following options are supported:
2211

2212
""caseSensitiveColumnNames"" (true or false; disabled by default),
2213

Thomas Mueller's avatar
Thomas Mueller committed
2214
""charset"" (for example 'UTF-8'),
2215

Thomas Mueller's avatar
Thomas Mueller committed
2216
""escape"" (the character that escapes the field delimiter),
2217

Thomas Mueller's avatar
Thomas Mueller committed
2218
""fieldDelimiter"" (a double quote by default),
2219

thomasmueller's avatar
thomasmueller committed
2220
""fieldSeparator"" (a comma by default),
2221

2222
""lineComment"" (disabled by default),
2223

2224
""lineSeparator"" (the line separator used for writing; ignored for reading),
2225

Thomas Mueller's avatar
Thomas Mueller committed
2226 2227
""null"", Support reading existing CSV files that contain explicit ""null"" delimiters.
Note that an empty, unquoted values are also treated as null.
2228

2229
""preserveWhitespace"" (true or false; disabled by default),
2230

2231
""writeColumnHeader"" (true or false; enabled by default).
2232

Thomas Mueller's avatar
Thomas Mueller committed
2233
For a newline or other special character, use STRINGDECODE as in the example above.
Thomas Mueller's avatar
Thomas Mueller committed
2234
A space needs to be escaped with a backslash (""'\ '""), and
Thomas Mueller's avatar
Thomas Mueller committed
2235 2236 2237
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.
Thomas Mueller's avatar
Thomas Mueller committed
2238
","
2239
CALL CSVWRITE('test2.csv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=|');
Thomas Mueller's avatar
Thomas Mueller committed
2240 2241
"

2242 2243 2244
"Other Grammar","Data Type","
intType | booleanType | tinyintType | smallintType | bigintType | identityType
    | decimalType | doubleType | realType | dateType | timeType | timestampType
2245 2246
    | timestampWithTimeZoneType | binaryType | otherType | varcharType
    | varcharIgnorecaseType | charType | blobType | clobType | uuidType
2247
    | arrayType | enumType | intervalType
Thomas Mueller's avatar
Thomas Mueller committed
2248
","
2249
A data type definition.
Thomas Mueller's avatar
Thomas Mueller committed
2250
","
2251
INT
Thomas Mueller's avatar
Thomas Mueller committed
2252 2253
"

2254 2255
"Other Grammar","Date","
DATE 'yyyy-MM-dd'
Thomas Mueller's avatar
Thomas Mueller committed
2256
","
2257
A date literal. The limitations are the same as for the Java data type
2258
""java.sql.Date"", but for compatibility with other databases the suggested minimum
2259
and maximum years are 0001 and 9999.
Thomas Mueller's avatar
Thomas Mueller committed
2260
","
2261
DATE '2004-12-31'
Thomas Mueller's avatar
Thomas Mueller committed
2262 2263
"

2264
"Other Grammar","Decimal","
2265 2266
[ + | - ] { { number [ . number ] } | { . number } }
[ E [ + | - ] expNumber [...] ] ]
2267
","
Thomas Mueller's avatar
Thomas Mueller committed
2268 2269 2270 2271 2272 2273
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)"".
2274
","
Thomas Mueller's avatar
Thomas Mueller committed
2275 2276 2277
SELECT -1600.05
SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
2278 2279
"

2280 2281 2282 2283 2284 2285 2286 2287
"Other Grammar","Delete search condition","
[ WHERE expression ] [ LIMIT term ]
","
Search condition for DELETE statement.
","
WHERE ID = 2
"

2288 2289
"Other Grammar","Digit","
0-9
Thomas Mueller's avatar
Thomas Mueller committed
2290
","
2291
A digit.
Thomas Mueller's avatar
Thomas Mueller committed
2292
","
2293
0
Thomas Mueller's avatar
Thomas Mueller committed
2294 2295
"

2296 2297
"Other Grammar","Dollar Quoted String","
$$anythingExceptTwoDollarSigns$$
Thomas Mueller's avatar
Thomas Mueller committed
2298
","
2299 2300 2301
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.
Thomas Mueller's avatar
Thomas Mueller committed
2302
","
2303
$$John's car$$
Thomas Mueller's avatar
Thomas Mueller committed
2304 2305
"

2306 2307
"Other Grammar","Expression","
andCondition [ { OR andCondition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2308
","
2309
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2310
","
2311
ID=1 OR NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2312 2313
"

2314
"Other Grammar","Factor","
2315
term [ { { * | / | % } term } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2316
","
2317
A value or a numeric factor.
Thomas Mueller's avatar
Thomas Mueller committed
2318
","
2319
ID * 10
Thomas Mueller's avatar
Thomas Mueller committed
2320 2321
"

2322 2323
"Other Grammar","Hex","
{ { digit | a-f | A-F } { digit | a-f | A-F } } [...]
Thomas Mueller's avatar
Thomas Mueller committed
2324
","
2325 2326
The hexadecimal representation of a number or of bytes. Two characters are one
byte.
Thomas Mueller's avatar
Thomas Mueller committed
2327
","
2328
cafe
Thomas Mueller's avatar
Thomas Mueller committed
2329 2330
"

2331 2332
"Other Grammar","Hex Number","
[ + | - ] 0x hex
Thomas Mueller's avatar
Thomas Mueller committed
2333
","
2334
A number written in hexadecimal notation.
Thomas Mueller's avatar
Thomas Mueller committed
2335
","
2336
0xff
Thomas Mueller's avatar
Thomas Mueller committed
2337 2338
"

2339 2340
"Other Grammar","Index Column","
columnName [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
Thomas Mueller's avatar
Thomas Mueller committed
2341
","
2342 2343 2344
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.
Thomas Mueller's avatar
Thomas Mueller committed
2345
","
2346
NAME
Thomas Mueller's avatar
Thomas Mueller committed
2347 2348
"

2349 2350 2351 2352 2353 2354 2355 2356 2357 2358 2359
"Other Grammar","Insert columns and source","
{ [ ( columnName [,...] ) ]
    { VALUES { ( { DEFAULT | expression } [,...] ) } [,...]
        | [ DIRECT ] [ SORTED ] select } } |
    { SET { columnName = { DEFAULT | expression } } [,...] }
","
Names of columns and their values for INSERT statement.
","
(ID, NAME) VALUES (1, 'Test')
"

Thomas Mueller's avatar
Thomas Mueller committed
2360
"Other Grammar","Int","
2361
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2362 2363 2364 2365 2366 2367 2368
","
The maximum integer number is 2147483647, the minimum is -2147483648.
","
10
"

"Other Grammar","Long","
2369
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2370 2371 2372 2373 2374 2375
","
Long numbers are between -9223372036854775808 and 9223372036854775807.
","
100000
"

2376
"Other Grammar","Name","
2377
{ { A-Z|_ } [ { A-Z|_|0-9 } [...] ] } | quotedName
Thomas Mueller's avatar
Thomas Mueller committed
2378
","
2379
Names are not case sensitive. There is no maximum name length.
Thomas Mueller's avatar
Thomas Mueller committed
2380
","
2381
TEST
Thomas Mueller's avatar
Thomas Mueller committed
2382 2383
"

2384 2385
"Other Grammar","Null","
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2386
","
2387
NULL is a value without data type and means 'unknown value'.
Thomas Mueller's avatar
Thomas Mueller committed
2388
","
2389
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2390 2391
"

2392 2393 2394 2395 2396 2397 2398 2399
"Other Grammar","Number","
digit [...]
","
The maximum length of the number depends on the data type used.
","
100
"

Thomas Mueller's avatar
Thomas Mueller committed
2400
"Other Grammar","Numeric","
Thomas Mueller's avatar
Thomas Mueller committed
2401
decimal | int | long | hexNumber
Thomas Mueller's avatar
Thomas Mueller committed
2402
","
Thomas Mueller's avatar
Thomas Mueller committed
2403
The data type of a numeric value is always the lowest possible for the given value.
Thomas Mueller's avatar
Thomas Mueller committed
2404 2405 2406 2407 2408 2409 2410
If the number contains a dot this is decimal; otherwise it is int, long, or decimal (depending on the value).
","
SELECT -1600.05
SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
"

2411 2412
"Other Grammar","Operand","
summand [ { || summand } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2413
","
2414
A value or a concatenation of values.
Thomas Mueller's avatar
Thomas Mueller committed
2415
In the default mode, the result is NULL if either parameter is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2416
","
2417
'Hi' || ' Eva'
Thomas Mueller's avatar
Thomas Mueller committed
2418 2419
"

2420 2421
"Other Grammar","Order","
{ int | expression } [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
Thomas Mueller's avatar
Thomas Mueller committed
2422
","
2423 2424 2425
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.
Thomas Mueller's avatar
Thomas Mueller committed
2426
","
2427
NAME DESC NULLS LAST
Thomas Mueller's avatar
Thomas Mueller committed
2428 2429
"

2430 2431
"Other Grammar","Quoted Name","
""anythingExceptDoubleQuote""
Thomas Mueller's avatar
Thomas Mueller committed
2432
","
2433 2434 2435
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.
Thomas Mueller's avatar
Thomas Mueller committed
2436
","
2437
""FirstName""
Thomas Mueller's avatar
Thomas Mueller committed
2438 2439
"

2440 2441 2442
"Other Grammar","Referential Constraint","
FOREIGN KEY ( columnName [,...] )
REFERENCES [ refTableName ] [ ( refColumnName [,...] ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2443
[ ON DELETE referentialAction ] [ ON UPDATE referentialAction ]
Thomas Mueller's avatar
Thomas Mueller committed
2444
","
Thomas Mueller's avatar
Thomas Mueller committed
2445 2446 2447
Defines a referential constraint.
If the table name is not specified, then the same table is referenced.
RESTRICT is the default action.
Thomas Mueller's avatar
Thomas Mueller committed
2448 2449 2450
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.
Thomas Mueller's avatar
Thomas Mueller committed
2451
","
2452
FOREIGN KEY(ID) REFERENCES TEST(ID)
Thomas Mueller's avatar
Thomas Mueller committed
2453 2454
"

Thomas Mueller's avatar
Thomas Mueller committed
2455 2456 2457 2458 2459 2460 2461 2462 2463 2464 2465
"Other Grammar","Referential Action","
CASCADE | RESTRICT | NO ACTION | SET { DEFAULT | NULL }
","
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.
","
FOREIGN KEY(ID) REFERENCES TEST(ID) ON UPDATE CASCADE
"

2466
"Other Grammar","Script Compression Encryption","
2467 2468
[ COMPRESSION { DEFLATE | LZF | ZIP | GZIP } ]
[ CIPHER cipher PASSWORD string ]
Thomas Mueller's avatar
Thomas Mueller committed
2469
","
2470 2471
The compression and encryption algorithm to use for script files.
When using encryption, only DEFLATE and LZF are supported.
Thomas Mueller's avatar
Thomas Mueller committed
2472 2473 2474 2475 2476
LZF is faster but uses more space.
","
COMPRESSION LZF
"

2477 2478
"Other Grammar","Select Expression","
* | expression [ [ AS ] columnAlias ] | tableAlias.*
Thomas Mueller's avatar
Thomas Mueller committed
2479
","
2480
An expression in a SELECT statement.
Thomas Mueller's avatar
Thomas Mueller committed
2481
","
2482
ID AS VALUE
Thomas Mueller's avatar
Thomas Mueller committed
2483 2484
"

2485 2486 2487 2488 2489 2490 2491 2492 2493 2494 2495 2496 2497
"Other Grammar","Sequence options","
[ START WITH long ]
[ INCREMENT BY long ]
[ MINVALUE long | NOMINVALUE | NO MINVALUE ]
[ MAXVALUE long | NOMAXVALUE | NO MAXVALUE ]
[ CYCLE long | NOCYCLE | NO CYCLE ]
[ CACHE long | NOCACHE | NO CACHE ]
","
Options of a sequence.
","
START WITH 1
"

2498 2499 2500 2501 2502 2503 2504 2505 2506
"Other Grammar","Set clause list","
{ { columnName = { DEFAULT | expression } } [,...] } |
    { ( columnName [,...] ) = ( select ) }
","
List of SET clauses.
","
NAME = 'Test', VALUE = 2
"

2507 2508
"Other Grammar","String","
'anythingExceptSingleQuote'
Thomas Mueller's avatar
Thomas Mueller committed
2509
","
2510 2511
A string starts and ends with a single quote. Two single quotes can be used to
create a single quote inside a string.
Thomas Mueller's avatar
Thomas Mueller committed
2512
","
2513
'John''s car'
Thomas Mueller's avatar
Thomas Mueller committed
2514 2515
"

2516 2517
"Other Grammar","Summand","
factor [ { { + | - } factor } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2518
","
Thomas Mueller's avatar
Thomas Mueller committed
2519
A value or a numeric sum.
Thomas Mueller's avatar
Thomas Mueller committed
2520

Thomas Mueller's avatar
Thomas Mueller committed
2521
Please note the text concatenation operator is ""||"".
Thomas Mueller's avatar
Thomas Mueller committed
2522
","
2523
ID + 20
Thomas Mueller's avatar
Thomas Mueller committed
2524 2525
"

2526
"Other Grammar","Table Expression","
2527 2528
{ [ schemaName. ] tableName | ( select ) | valuesExpression }
[ [ AS ] newTableAlias [ ( columnName [,...] ) ] ]
2529
[ USE INDEX ([ indexName [,...] ]) ]
2530 2531
[ { { LEFT | RIGHT } [ OUTER ] | [ INNER ] | CROSS | NATURAL }
    JOIN tableExpression [ ON expression ] ]
Thomas Mueller's avatar
Thomas Mueller committed
2532
","
2533 2534 2535
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.
Thomas Mueller's avatar
Thomas Mueller committed
2536
","
2537
TEST AS T LEFT JOIN TEST AS T1 ON T.ID = T1.ID
Thomas Mueller's avatar
Thomas Mueller committed
2538 2539
"

2540 2541 2542 2543 2544 2545 2546 2547 2548
"Other Grammar","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.
","
SELECT * FROM (VALUES(1, 'Hello'), (2, 'World')) AS V;
"

2549 2550
"Other Grammar","Window name or specification","
windowName | windowSpecification
2551
","
2552
A window name or inline specification for a window function or aggregate.
2553

2554 2555 2556
Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
2557
W1
2558
(ORDER BY ID)
2559 2560 2561 2562 2563 2564 2565 2566 2567 2568 2569
"

"Other Grammar","Window specification","
([existingWindowName]
[PARTITION BY expression [,...]] [ORDER BY order [,...]]
[windowFrame])
","
A window specification for a window, window function or aggregate.
","
()
(W1 ORDER BY ID)
2570 2571
(PARTITION BY CATEGORY)
(PARTITION BY CATEGORY ORDER BY NAME, ID)
2572 2573 2574 2575
(ORDER BY Y RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES)
"

"Other Grammar","Window frame","
2576
ROWS|RANGE|GROUP
2577
{windowFramePreceding|BETWEEN windowFrameBound AND windowFrameBound}
2578 2579 2580
[EXCLUDE {CURRENT ROW|GROUP|TIES|NO OTHERS}]
","
A window frame clause.
2581
May be specified only for aggregates and FIRST_VALUE(), LAST_VALUE(), and NTH_VALUE() window functions.
2582 2583
","
RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE GROUP
2584 2585
"

2586 2587 2588 2589 2590 2591 2592 2593 2594 2595 2596
"Other Grammar","Window frame preceding","
UNBOUNDED PRECEDING|value PRECEDING|CURRENT ROW
","
A window frame preceding clause.
If value is specified it should be non-negative value or parameter.
","
UNBOUNDED PRECEDING
1 PRECEDING
CURRENT ROW
"

2597 2598 2599
"Other Grammar","Window frame bound","
UNBOUNDED PRECEDING|value PRECEDING|CURRENT ROW
    |value FOLLOWING|UNBOUNDED FOLLOWING
2600
","
2601
A window frame bound clause.
2602 2603
If value is specified it should be non-negative value or parameter.
","
2604
UNBOUNDED PRECEDING
2605 2606 2607 2608 2609
UNBOUNDED FOLLOWING
1 FOLLOWING
CURRENT ROW
"

2610 2611 2612 2613 2614 2615 2616 2617 2618 2619 2620 2621
"Other Grammar","Term","
value
    | columnName
    | ?[ int ]
    | NEXT VALUE FOR sequenceName
    | function
    | { - | + } term
    | ( expression )
    | select
    | case
    | caseWhen
    | tableAlias.columnName
2622
    | userDefinedFunctionName
Thomas Mueller's avatar
Thomas Mueller committed
2623
","
2624
A value. Parameters can be indexed, for example ""?1"" meaning the first parameter.
Thomas Mueller's avatar
Thomas Mueller committed
2625
Each table has a pseudo-column named ""_ROWID_"" that contains the unique row identifier.
Thomas Mueller's avatar
Thomas Mueller committed
2626
","
2627 2628 2629 2630
'Hello'
"

"Other Grammar","Time","
2631
TIME [ WITHOUT TIME ZONE ] 'hh:mm:ss[.nnnnnnnnn]'
2632
","
2633
A time literal. A value is between 0:00:00 and 23:59:59.999999999
2634
and has nanosecond resolution.
2635 2636 2637 2638 2639
","
TIME '23:59:59'
"

"Other Grammar","Timestamp","
2640
TIMESTAMP [ WITHOUT TIME ZONE ] 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]'
2641 2642
","
A timestamp literal. The limitations are the same as for the Java data type
2643
""java.sql.Timestamp"", but for compatibility with other databases the suggested
2644 2645 2646 2647 2648
minimum and maximum years are 0001 and 9999.
","
TIMESTAMP '2005-12-31 23:59:59'
"

2649
"Other Grammar","Timestamp with time zone","
2650
TIMESTAMP WITH TIME ZONE 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]
2651 2652 2653 2654 2655 2656 2657 2658 2659 2660 2661
[Z | { - | + } timeZoneOffsetString | timeZoneNameString ]'
","
A timestamp with time zone literal.
If name of time zone is specified it will be converted to time zone offset.
","
TIMESTAMP WITH TIME ZONE '2005-12-31 23:59:59Z'
TIMESTAMP WITH TIME ZONE '2005-12-31 23:59:59-10:00'
TIMESTAMP WITH TIME ZONE '2005-12-31 23:59:59.123+05'
TIMESTAMP WITH TIME ZONE '2005-12-31 23:59:59.123456789 Europe/London'
"

2662 2663 2664 2665 2666 2667 2668 2669
"Other Grammar","Date and time","
date | time | timestamp | timestampWithTimeZone
","
A literal value of any date-time data type.
","
TIMESTAMP '1999-01-31 10:00:00'
"

2670 2671 2672 2673 2674 2675 2676 2677 2678 2679 2680 2681 2682 2683 2684 2685 2686 2687 2688 2689 2690 2691 2692 2693 2694 2695 2696 2697 2698 2699 2700 2701 2702 2703 2704 2705 2706 2707 2708 2709 2710 2711 2712 2713 2714 2715 2716 2717 2718 2719 2720 2721 2722 2723 2724 2725 2726 2727 2728 2729 2730
"Other Grammar","INTERVAL YEAR","
INTERVAL [-|+] '[-|+]yearInt' YEAR
","
An INTERVAL YEAR literal.
","
INTERVAL '10' YEAR
"

"Other Grammar","INTERVAL MONTH","
INTERVAL [-|+] '[-|+]monthInt' MONTH
","
An INTERVAL MONTH literal.
","
INTERVAL '10' MONTH
"

"Other Grammar","INTERVAL DAY","
INTERVAL [-|+] '[-|+]dayInt' DAY
","
An INTERVAL DAY literal.
","
INTERVAL '10' DAY
"

"Other Grammar","INTERVAL HOUR","
INTERVAL [-|+] '[-|+]hourInt' HOUR
","
An INTERVAL HOUR literal.
","
INTERVAL '10' HOUR
"

"Other Grammar","INTERVAL MINUTE","
INTERVAL [-|+] '[-|+]minuteInt' MINUTE
","
An INTERVAL MINUTE literal.
","
INTERVAL '10' MINUTE
"

"Other Grammar","INTERVAL SECOND","
INTERVAL [-|+] '[-|+]secondInt[.nnnnnnnnn]' SECOND
","
An INTERVAL SECOND literal.
","
INTERVAL '10.123' SECOND
"

"Other Grammar","INTERVAL YEAR TO MONTH","
INTERVAL [-|+] '[-|+]yearInt-monthInt' YEAR TO MONTH
","
An INTERVAL YEAR TO MONTH literal.
","
INTERVAL '1-6' YEAR TO MONTH
"

"Other Grammar","INTERVAL DAY TO HOUR","
INTERVAL [-|+] '[-|+]dayInt hoursInt' DAY TO HOUR
","
An INTERVAL DAY TO HOUR literal.
","
2731
INTERVAL '10 11' DAY TO HOUR
2732 2733 2734 2735 2736 2737 2738 2739 2740 2741 2742 2743 2744 2745 2746 2747 2748 2749 2750 2751 2752 2753 2754 2755 2756 2757 2758 2759 2760 2761 2762 2763 2764 2765 2766 2767 2768 2769 2770 2771 2772 2773 2774 2775
"

"Other Grammar","INTERVAL DAY TO MINUTE","
INTERVAL [-|+] '[-|+]dayInt hh:mm' DAY TO MINUTE
","
An INTERVAL DAY TO MINUTE literal.
","
INTERVAL '10 11:12' DAY TO MINUTE
"

"Other Grammar","INTERVAL DAY TO SECOND","
INTERVAL [-|+] '[-|+]dayInt hh:mm:ss[.nnnnnnnnn]' DAY TO SECOND
","
An INTERVAL DAY TO SECOND literal.
","
INTERVAL '10 11:12:13.123' DAY TO SECOND
"

"Other Grammar","INTERVAL HOUR TO MINUTE","
INTERVAL [-|+] '[-|+]hh:mm' HOUR TO MINUTE
","
An INTERVAL HOUR TO MINUTE literal.
","
INTERVAL '10:11' HOUR TO MINUTE
"

"Other Grammar","INTERVAL HOUR TO SECOND","
INTERVAL [-|+] '[-|+]hh:mm:ss[.nnnnnnnnn]' HOUR TO SECOND
","
An INTERVAL HOUR TO SECOND literal.
","
INTERVAL '10:11:12.123' HOUR TO SECOND
"

"Other Grammar","INTERVAL MINUTE TO SECOND","
INTERVAL [-|+] '[-|+]mm:ss[.nnnnnnnnn]' MINUTE TO SECOND
","
An INTERVAL MINUTE TO SECOND literal.
","
INTERVAL '11:12.123' MINUTE TO SECOND
"

"Other Grammar","Interval","
intervalYear | intervalMonth | intervalDay | intervalHour | intervalMinute
2776 2777 2778
    | intervalSecond | intervalYearToMonth | intervalDayToHour
    | intervalDayToMinute | intervalDayToSecond | intervalHourToMinute
    | intervalHourToSecond | intervalMinuteToSecond
2779 2780 2781 2782 2783 2784
","
An interval literal.
","
INTERVAL '1-2' YEAR TO MONTH
"

2785
"Other Grammar","Value","
2786
string | dollarQuotedString | numeric | dateAndTime | boolean | bytes
2787
    | interval | array | null
2788
","
Thomas Mueller's avatar
Thomas Mueller committed
2789
A literal value of any data type, or null.
2790 2791
","
10
Thomas Mueller's avatar
Thomas Mueller committed
2792 2793 2794 2795 2796 2797 2798
"

"Data Types","INT Type","
INT | INTEGER | MEDIUMINT | INT4 | SIGNED
","
Possible values: -2147483648 to 2147483647.

2799
Mapped to ""java.lang.Integer"".
Thomas Mueller's avatar
Thomas Mueller committed
2800 2801 2802 2803 2804 2805 2806 2807 2808
","
INT
"

"Data Types","BOOLEAN Type","
BOOLEAN | BIT | BOOL
","
Possible values: TRUE and FALSE.

2809
Mapped to ""java.lang.Boolean"".
Thomas Mueller's avatar
Thomas Mueller committed
2810 2811 2812 2813 2814 2815 2816 2817 2818
","
BOOLEAN
"

"Data Types","TINYINT Type","
TINYINT
","
Possible values are: -128 to 127.

2819
Mapped to ""java.lang.Byte"".
Thomas Mueller's avatar
Thomas Mueller committed
2820 2821 2822 2823 2824 2825 2826 2827 2828
","
TINYINT
"

"Data Types","SMALLINT Type","
SMALLINT | INT2 | YEAR
","
Possible values: -32768 to 32767.

2829
Mapped to ""java.lang.Short"".
Thomas Mueller's avatar
Thomas Mueller committed
2830 2831 2832 2833 2834 2835 2836 2837 2838
","
SMALLINT
"

"Data Types","BIGINT Type","
BIGINT | INT8
","
Possible values: -9223372036854775808 to 9223372036854775807.

2839
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2840 2841 2842 2843 2844 2845 2846 2847 2848 2849 2850
","
BIGINT
"

"Data Types","IDENTITY Type","
IDENTITY
","
Auto-Increment value. Possible values: -9223372036854775808 to
9223372036854775807. Used values are never re-used, even when the transaction is
rolled back.

2851
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2852 2853 2854 2855 2856
","
IDENTITY
"

"Data Types","DECIMAL Type","
2857
{ DECIMAL | NUMBER | DEC | NUMERIC } ( precisionInt [ , scaleInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
2858 2859 2860 2861
","
Data type with fixed precision and scale. This data type is recommended for
storing currency values.

2862
Mapped to ""java.math.BigDecimal"".
Thomas Mueller's avatar
Thomas Mueller committed
2863 2864 2865 2866 2867
","
DECIMAL(20, 2)
"

"Data Types","DOUBLE Type","
2868
{ DOUBLE [ PRECISION ] | FLOAT [ ( precisionInt ) ] | FLOAT8 }
Thomas Mueller's avatar
Thomas Mueller committed
2869
","
Thomas Mueller's avatar
Thomas Mueller committed
2870
A floating point number. Should not be used to represent currency values, because
Thomas Mueller's avatar
Thomas Mueller committed
2871
of rounding problems.
2872
If precision value is specified for FLOAT type name, it should be from 25 to 53.
Thomas Mueller's avatar
Thomas Mueller committed
2873

2874
Mapped to ""java.lang.Double"".
Thomas Mueller's avatar
Thomas Mueller committed
2875 2876 2877 2878 2879
","
DOUBLE
"

"Data Types","REAL Type","
2880
{ REAL | FLOAT ( precisionInt ) | FLOAT4 }
Thomas Mueller's avatar
Thomas Mueller committed
2881
","
Thomas Mueller's avatar
Thomas Mueller committed
2882
A single precision floating point number. Should not be used to represent currency
Thomas Mueller's avatar
Thomas Mueller committed
2883
values, because of rounding problems.
2884
Precision value for FLOAT type name should be from 0 to 24.
Thomas Mueller's avatar
Thomas Mueller committed
2885

2886
Mapped to ""java.lang.Float"".
Thomas Mueller's avatar
Thomas Mueller committed
2887 2888 2889 2890 2891
","
REAL
"

"Data Types","TIME Type","
2892
TIME [ ( precisionInt ) ] [ WITHOUT TIME ZONE ]
Thomas Mueller's avatar
Thomas Mueller committed
2893
","
2894
The time data type. The format is hh:mm:ss[.nnnnnnnnn].
2895
If fractional seconds precision is specified it should be from 0 to 9, 0 is default.
Thomas Mueller's avatar
Thomas Mueller committed
2896

2897
Mapped to ""java.sql.Time"". When converted to a ""java.sql.Date"", the date is set to ""1970-01-01"".
2898
""java.time.LocalTime"" is also supported on Java 8 and later versions.
Evgenij Ryazanov's avatar
Evgenij Ryazanov committed
2899
Resolution of ""java.sql.Time"" is limited to milliseconds, use ""String"" or ""java.time.LocalTime"" if you need nanosecond resolution.
Thomas Mueller's avatar
Thomas Mueller committed
2900 2901 2902 2903 2904 2905 2906
","
TIME
"

"Data Types","DATE Type","
DATE
","
Thomas Mueller's avatar
Thomas Mueller committed
2907
The date data type. The format is yyyy-MM-dd.
Thomas Mueller's avatar
Thomas Mueller committed
2908

2909
Mapped to ""java.sql.Date"", with the time set to ""00:00:00""
Thomas Mueller's avatar
Thomas Mueller committed
2910
(or to the next possible time if midnight doesn't exist for the given date and timezone due to a daylight saving change).
2911
""java.time.LocalDate"" is also supported on Java 8 and later versions.
Thomas Mueller's avatar
Thomas Mueller committed
2912 2913 2914 2915 2916
","
DATE
"

"Data Types","TIMESTAMP Type","
2917
{ TIMESTAMP [ ( precisionInt ) ] [ WITHOUT TIME ZONE ]
2918
    | DATETIME [ ( precisionInt ) ] | SMALLDATETIME }
Thomas Mueller's avatar
Thomas Mueller committed
2919
","
Thomas Mueller's avatar
Thomas Mueller committed
2920
The timestamp data type. The format is yyyy-MM-dd hh:mm:ss[.nnnnnnnnn].
2921
Stored internally as a BCD-encoded date, and nanoseconds since midnight.
2922
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
2923
Fractional seconds precision of SMALLDATETIME is always 0 and cannot be specified.
Thomas Mueller's avatar
Thomas Mueller committed
2924

2925 2926
Mapped to ""java.sql.Timestamp"" (""java.util.Date"" may be used too).
""java.time.LocalDateTime"" is also supported on Java 8 and later versions.
Thomas Mueller's avatar
Thomas Mueller committed
2927 2928 2929 2930
","
TIMESTAMP
"

2931
"Data Types","TIMESTAMP WITH TIME ZONE Type","
2932
TIMESTAMP [ ( precisionInt ) ] WITH TIME ZONE
2933
","
2934
The timestamp with time zone data type.
2935
Stored internally as a BCD-encoded date, nanoseconds since midnight, and time zone offset in minutes.
2936
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
2937

2938 2939 2940 2941 2942 2943 2944
Mapped to ""org.h2.api.TimestampWithTimeZone"".
""java.time.OffsetDateTime"" and ""java.time.Instant"" are also supported on Java 8 and later versions.

Values of this data type are compared by UTC values. It means that ""2010-01-01 10:00:00+01"" is greater than ""2010-01-01 11:00:00+03"".

Conversion to ""TIMESTAMP"" uses time zone offset to get UTC time and converts it to local time using the system time zone.
Conversion from ""TIMESTAMP"" does the same operations in reverse and sets time zone offset to offset of the system time zone.
2945
","
2946
TIMESTAMP WITH TIME ZONE
2947 2948
"

Thomas Mueller's avatar
Thomas Mueller committed
2949
"Data Types","BINARY Type","
2950 2951
{ BINARY | VARBINARY | BINARY VARYING
    | LONGVARBINARY | RAW | BYTEA }
2952
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2953
","
2954 2955 2956 2957 2958
Represents a byte array. For very long arrays, use BLOB.
The maximum size is 2 GB, but the whole object is kept in
memory when using this data type. The precision is a size constraint;
only the actual data is persisted. For large text data BLOB or CLOB
should be used.
Thomas Mueller's avatar
Thomas Mueller committed
2959 2960 2961 2962 2963 2964 2965 2966 2967

Mapped to byte[].
","
BINARY(1000)
"

"Data Types","OTHER Type","
OTHER
","
Thomas Mueller's avatar
Thomas Mueller committed
2968 2969 2970 2971 2972
This type allows storing serialized Java objects. Internally, a byte array is used.
Serialization and deserialization is done on the client side only.
Deserialization is only done when ""getObject"" is called.
Java operations cannot be executed inside the database engine for security reasons.
Use ""PreparedStatement.setObject"" to store values.
Thomas Mueller's avatar
Thomas Mueller committed
2973

2974
Mapped to ""java.lang.Object"" (or any subclass).
Thomas Mueller's avatar
Thomas Mueller committed
2975 2976 2977 2978 2979
","
OTHER
"

"Data Types","VARCHAR Type","
2980
{ VARCHAR | CHARACTER VARYING | LONGVARCHAR | VARCHAR2 | NVARCHAR
2981
    | NVARCHAR2 | VARCHAR_CASESENSITIVE} [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2982
","
Thomas Mueller's avatar
Thomas Mueller committed
2983
A Unicode String.
Thomas Mueller's avatar
Thomas Mueller committed
2984 2985 2986 2987 2988 2989 2990
Use two single quotes ('') to create a quote.

The maximum precision is ""Integer.MAX_VALUE"".
The precision is a size constraint; only the actual data is persisted.

The whole text is loaded into memory when using this data type.
For large text data CLOB should be used; see there for details.
Thomas Mueller's avatar
Thomas Mueller committed
2991

2992
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
2993 2994 2995 2996 2997
","
VARCHAR(255)
"

"Data Types","VARCHAR_IGNORECASE Type","
2998
VARCHAR_IGNORECASE [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2999
","
Thomas Mueller's avatar
Thomas Mueller committed
3000
Same as VARCHAR, but not case sensitive when comparing.
Thomas Mueller's avatar
Thomas Mueller committed
3001 3002 3003 3004 3005 3006 3007
Stored in mixed case.

The maximum precision is ""Integer.MAX_VALUE"".
The precision is a size constraint; only the actual data is persisted.

The whole text is loaded into memory when using this data type.
For large text data CLOB should be used; see there for details.
Thomas Mueller's avatar
Thomas Mueller committed
3008

3009
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3010 3011 3012 3013 3014
","
VARCHAR_IGNORECASE
"

"Data Types","CHAR Type","
3015
{ CHAR | CHARACTER | NCHAR } [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3016
","
Thomas Mueller's avatar
Thomas Mueller committed
3017 3018 3019
A Unicode String.
This type is supported for compatibility with other databases and older applications.
The difference to VARCHAR is that trailing spaces are ignored and not persisted.
Thomas Mueller's avatar
Thomas Mueller committed
3020

Thomas Mueller's avatar
Thomas Mueller committed
3021 3022
The maximum precision is ""Integer.MAX_VALUE"".
The precision is a size constraint; only the actual data is persisted.
Thomas Mueller's avatar
Thomas Mueller committed
3023

Thomas Mueller's avatar
Thomas Mueller committed
3024
The whole text is kept in memory when using this data type.
Thomas Mueller's avatar
Thomas Mueller committed
3025
For large text data CLOB should be used; see there for details.
Thomas Mueller's avatar
Thomas Mueller committed
3026

3027
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3028 3029 3030 3031 3032
","
CHAR(10)
"

"Data Types","BLOB Type","
3033 3034
{ BLOB | BINARY LARGE OBJECT
    | TINYBLOB | MEDIUMBLOB | LONGBLOB | IMAGE | OID }
3035
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3036 3037 3038
","
Like BINARY, but intended for very large values such as files or images. Unlike
when using BINARY, large objects are not kept fully in-memory. Use
3039
""PreparedStatement.setBinaryStream"" to store values. See also CLOB and
Thomas Mueller's avatar
Thomas Mueller committed
3040 3041
Advanced / Large Objects.

3042
Mapped to ""java.sql.Blob"" (""java.io.InputStream"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3043 3044 3045 3046 3047
","
BLOB
"

"Data Types","CLOB Type","
3048 3049
{ CLOB | CHARACTER LARGE OBJECT
    | TINYTEXT | TEXT | MEDIUMTEXT | LONGTEXT | NTEXT | NCLOB }
3050
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3051 3052 3053 3054 3055
","
CLOB is like VARCHAR, but intended for very large values. Unlike when using
VARCHAR, large CLOB objects are not kept fully in-memory; instead, they are streamed.
CLOB should be used for documents and texts with arbitrary size such as XML or
HTML documents, text files, or memo fields of unlimited size. Use
3056
""PreparedStatement.setCharacterStream"" to store values. See also Advanced / Large Objects.
Thomas Mueller's avatar
Thomas Mueller committed
3057 3058 3059 3060 3061

VARCHAR should be used for text with relatively short average size (for example
shorter than 200 characters). Short CLOB values are stored inline, but there is
an overhead compared to VARCHAR.

3062
Mapped to ""java.sql.Clob"" (""java.io.Reader"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3063 3064 3065 3066 3067 3068 3069
","
CLOB
"

"Data Types","UUID Type","
UUID
","
Thomas Mueller's avatar
Thomas Mueller committed
3070 3071 3072 3073
Universally unique identifier. This is a 128 bit value.
To store values, use ""PreparedStatement.setBytes"",
""setString"", or ""setObject(uuid)"" (where ""uuid"" is a ""java.util.UUID"").
""ResultSet.getObject"" will return a ""java.util.UUID"".
Thomas Mueller's avatar
Thomas Mueller committed
3074

Thomas Mueller's avatar
Thomas Mueller committed
3075 3076 3077 3078 3079
Please note that using an index on randomly generated data will
result on poor performance once there are millions of rows in a table.
The reason is that the cache behavior is very bad with randomly distributed data.
This is a problem for any database system.

Thomas Mueller's avatar
Thomas Mueller committed
3080
For details, see the documentation of ""java.util.UUID"".
Thomas Mueller's avatar
Thomas Mueller committed
3081 3082 3083 3084 3085 3086 3087
","
UUID
"

"Data Types","ARRAY Type","
ARRAY
","
Thomas Mueller's avatar
Thomas Mueller committed
3088
An array of values.
3089
Mapped to ""java.lang.Object[]"" (arrays of any non-primitive type are also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3090 3091 3092 3093


Use a value list (1, 2) or ""PreparedStatement.setObject(.., new Object[] {..})"" to store values,
and ""ResultSet.getObject(..)"" or ""ResultSet.getArray(..)"" to retrieve the values.
Thomas Mueller's avatar
Thomas Mueller committed
3094 3095 3096 3097
","
ARRAY
"

3098 3099 3100 3101 3102 3103 3104 3105 3106 3107 3108 3109 3110 3111
"Data Types","ENUM Type","
{ ENUM (string [, ... ]) }
","
A type with enumerated values.
Mapped to ""java.lang.Integer"".

The first provided value is mapped to 0, the
second mapped to 1, and so on.

Duplicate and empty values are not permitted.
","

ENUM('clubs', 'diamonds', 'hearts', 'spades')
"
3112 3113
"Data Types","GEOMETRY Type","
GEOMETRY
3114 3115 3116 3117 3118 3119 3120 3121 3122
    [({ GEOMETRY |
    { POINT
    | LINESTRING
    | POLYGON
    | MULTIPOINT
    | MULTILINESTRING
    | MULTIPOLYGON
    | GEOMETRYCOLLECTION } [Z|M|ZM]}
    [, sridInt] )]
3123
","
3124
A spatial geometry type.
3125 3126 3127 3128 3129
If additional constraints are not specified this type accepts all supported types of geometries.
A constraint with required geometry type and dimension system can be set by specifying name of the type and
dimension system. A whitespace between them is optional.
2D dimension system does not have a name and assumed if only a geometry type name is specified.
POINT means 2D point, POINT Z or POINTZ means 3D point.
3130
GEOMETRY constraint means no restrictions on type or dimension system of geometry.
3131 3132 3133
A constraint with required spatial reference system identifier (SRID) can be set by specifying this identifier.

Mapped to ""org.locationtech.jts.geom.Geometry"" if JTS library is in classpath and to ""java.lang.String"" otherwise.
3134 3135
May be represented in textual format using the WKT (well-known text) or EWKT (extended well-known text) format.
Values are stored internally in EWKB (extended well-known binary) format.
3136 3137
Only a subset of EWKB and EWKT features is supported.
Supported objects are POINT, LINESTRING, POLYGON, MULTIPOINT, MULTILINESTRING, MULTIPOLYGON, and GEOMETRYCOLLECTION.
3138
Supported dimension systems are 2D (XY), Z (XYZ), M (XYM), and ZM (XYZM).
3139
SRID (spatial reference system identifier) is supported.
3140

3141
Use a quoted string containing a WKT/EWKT formatted string or ""PreparedStatement.setObject()"" to store values,
3142 3143
and ""ResultSet.getObject(..)"" or ""ResultSet.getString(..)"" to retrieve the values.
","
3144
GEOMETRY
3145 3146 3147
GEOMETRY(POINT)
GEOMETRY(POINT Z)
GEOMETRY(POINT Z, 4326)
3148
GEOMETRY(GEOMETRY, 4326)
3149 3150
"

3151
"Data Types","INTERVAL Type","
3152 3153 3154 3155 3156 3157 3158
intervalYearType | intervalMonthType | intervalDayType
    | intervalHourType| intervalMinuteType | intervalSecondType
    | intervalYearToMonthType | intervalDayToHourType
    | intervalDayToMinuteType | intervalDayToSecondType
    | intervalHourToMinuteType | intervalHourToSecondType
    | intervalMinuteToSecondType
","
3159 3160
Interval data type.
There are two classes of intervals. Year-month intervals can store years and months.
3161 3162 3163 3164 3165 3166 3167 3168 3169 3170
Day-time intervals can store days, hours, minutes, and seconds.
Year-month intervals are comparable only with another year-month intervals.
Day-time intervals are comparable only with another day-time intervals.

Mapped to ""org.h2.api.Interval"".
","
INTERVAL DAY TO SECOND
"

"Interval Data Types","INTERVAL YEAR Type","
3171 3172 3173 3174 3175 3176 3177 3178 3179 3180
INTERVAL YEAR [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
","
INTERVAL YEAR
"

3181
"Interval Data Types","INTERVAL MONTH Type","
3182 3183 3184 3185 3186 3187 3188 3189 3190 3191
INTERVAL MONTH [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
","
INTERVAL MONTH
"

3192
"Interval Data Types","INTERVAL DAY Type","
3193 3194 3195 3196 3197 3198 3199 3200 3201 3202 3203
INTERVAL DAY [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL DAY
"

3204
"Interval Data Types","INTERVAL HOUR Type","
3205 3206 3207 3208 3209 3210 3211 3212 3213 3214 3215
INTERVAL HOUR [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL HOUR
"

3216
"Interval Data Types","INTERVAL MINUTE Type","
3217 3218 3219 3220 3221 3222 3223 3224 3225 3226 3227
INTERVAL MINUTE [ ( precisionInt ) ]
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL MINUTE
"

3228
"Interval Data Types","INTERVAL SECOND Type","
3229
INTERVAL SECOND [ ( precisionInt [, fractionalPrecisionInt ] ) ]
3230 3231 3232
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.
3233
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3234 3235 3236 3237 3238 3239 3240

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL SECOND
"

3241
"Interval Data Types","INTERVAL YEAR TO MONTH Type","
3242 3243 3244
INTERVAL YEAR [ ( precisionInt ) ] TO MONTH
","
Interval data type.
3245
If leading field precision is specified it should be from 1 to 18, 2 is default.
3246 3247 3248 3249 3250 3251

Mapped to ""org.h2.api.Interval"".
","
INTERVAL YEAR TO MONTH
"

3252
"Interval Data Types","INTERVAL DAY TO HOUR Type","
3253 3254 3255
INTERVAL DAY [ ( precisionInt ) ] TO HOUR
","
Interval data type.
3256
If leading field precision is specified it should be from 1 to 18, 2 is default.
3257 3258 3259 3260 3261 3262 3263

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL DAY TO HOUR
"

3264
"Interval Data Types","INTERVAL DAY TO MINUTE Type","
3265 3266 3267
INTERVAL DAY [ ( precisionInt ) ] TO MINUTE
","
Interval data type.
3268
If leading field precision is specified it should be from 1 to 18, 2 is default.
3269 3270 3271 3272 3273 3274 3275

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL DAY TO MINUTE
"

3276
"Interval Data Types","INTERVAL DAY TO SECOND Type","
3277
INTERVAL DAY [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3278 3279
","
Interval data type.
3280 3281
If leading field precision is specified it should be from 1 to 18, 2 is default.
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3282 3283 3284 3285 3286 3287 3288

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL DAY TO SECOND
"

3289
"Interval Data Types","INTERVAL HOUR TO MINUTE Type","
3290 3291 3292
INTERVAL HOUR [ ( precisionInt ) ] TO MINUTE
","
Interval data type.
3293
If leading field precision is specified it should be from 1 to 18, 2 is default.
3294 3295 3296 3297 3298 3299 3300

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL HOUR TO MINUTE
"

3301
"Interval Data Types","INTERVAL HOUR TO SECOND Type","
3302
INTERVAL HOUR [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3303 3304
","
Interval data type.
3305 3306
If leading field precision is specified it should be from 1 to 18, 2 is default.
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3307 3308 3309 3310 3311 3312 3313

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL HOUR TO SECOND
"

3314
"Interval Data Types","INTERVAL MINUTE TO SECOND Type","
3315
INTERVAL MINUTE [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3316 3317
","
Interval data type.
3318 3319
If leading field precision is specified it should be from 1 to 18, 2 is default.
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3320 3321 3322 3323 3324 3325 3326

Mapped to ""org.h2.api.Interval"".
""java.time.Duration"" is also supported on Java 8 and later versions.
","
INTERVAL MINUTE TO SECOND
"

Thomas Mueller's avatar
Thomas Mueller committed
3327
"Functions (Aggregate)","AVG","
3328
AVG ( [ DISTINCT ] { numeric } )
3329
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3330
","
3331 3332
The average (mean) value.
If no rows are selected, the result is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
3333
Aggregates are only allowed in select statements.
3334
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3335 3336 3337 3338
","
AVG(X)
"

3339
"Functions (Aggregate)","BIT_AND","
3340
BIT_AND(expression)
3341
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3342 3343 3344 3345 3346 3347 3348 3349 3350
","
The bitwise AND of all non-null values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
BIT_AND(ID)
"

"Functions (Aggregate)","BIT_OR","
3351
BIT_OR(expression)
3352
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3353 3354 3355 3356 3357 3358 3359 3360
","
The bitwise OR of all non-null values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
BIT_OR(ID)
"

Thomas Mueller's avatar
Thomas Mueller committed
3361
"Functions (Aggregate)","BOOL_AND","
3362
BOOL_AND(boolean)
3363
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3364
","
3365 3366 3367
Returns true if all expressions are true.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3368 3369 3370 3371 3372
","
BOOL_AND(ID>10)
"

"Functions (Aggregate)","BOOL_OR","
3373
BOOL_OR(boolean)
3374
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3375
","
3376 3377 3378
Returns true if any expression is true.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3379 3380 3381 3382 3383
","
BOOL_OR(NAME LIKE 'W%')
"

"Functions (Aggregate)","COUNT","
3384
COUNT( { * | { [ DISTINCT ] expression } } )
3385
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3386
","
3387 3388 3389 3390
The count of all row, or of the non-null values.
This method returns a long.
If no rows are selected, the result is 0.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3391 3392 3393 3394 3395
","
COUNT(*)
"

"Functions (Aggregate)","GROUP_CONCAT","
3396 3397
GROUP_CONCAT ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ]
3398
[ SEPARATOR expression ] )
3399
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3400
","
3401 3402 3403 3404 3405
Concatenates strings with a separator.
The default separator is a ',' (without space).
This method returns a string.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3406 3407 3408 3409
","
GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ')
"

3410 3411 3412
"Functions (Aggregate)","ARRAY_AGG","
ARRAY_AGG ( [ DISTINCT ] string
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] )
3413
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3414 3415 3416 3417 3418 3419 3420 3421 3422
","
Aggregate the value into an array.
This method returns an array.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
ARRAY_AGG(NAME ORDER BY ID)
"

Thomas Mueller's avatar
Thomas Mueller committed
3423
"Functions (Aggregate)","MAX","
3424
MAX(value)
3425
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3426
","
3427 3428 3429 3430
The highest value.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3431 3432 3433 3434 3435
","
MAX(NAME)
"

"Functions (Aggregate)","MIN","
3436
MIN(value)
3437
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3438
","
3439 3440 3441 3442
The lowest value.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3443 3444 3445 3446 3447
","
MIN(NAME)
"

"Functions (Aggregate)","SUM","
3448
SUM( [ DISTINCT ] { numeric } )
3449
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3450
","
3451 3452 3453
The sum of all values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
3454
The data type of the returned value depends on the parameter data type like this:
Thomas Mueller's avatar
Thomas Mueller committed
3455
""BOOLEAN, TINYINT, SMALLINT, INT -> BIGINT, BIGINT -> DECIMAL, REAL -> DOUBLE""
Thomas Mueller's avatar
Thomas Mueller committed
3456 3457 3458 3459 3460
","
SUM(X)
"

"Functions (Aggregate)","SELECTIVITY","
3461
SELECTIVITY(value)
3462
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3463
","
3464 3465 3466 3467 3468
Estimates the selectivity (0-100) of a value.
The value is defined as (100 * distinctCount / rowCount).
The selectivity of 0 rows is 0 (unknown).
Up to 10000 values are kept in memory.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3469 3470 3471 3472 3473
","
SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000
"

"Functions (Aggregate)","STDDEV_POP","
3474
STDDEV_POP( [ DISTINCT ] numeric )
3475
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3476
","
3477 3478 3479
The population standard deviation.
This method returns a double.
If no rows are selected, the result is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
3480 3481 3482 3483 3484 3485
Aggregates are only allowed in select statements.
","
STDDEV_POP(X)
"

"Functions (Aggregate)","STDDEV_SAMP","
3486
STDDEV_SAMP( [ DISTINCT ] numeric )
3487
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3488
","
3489 3490 3491
The sample standard deviation.
This method returns a double.
If no rows are selected, the result is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
3492 3493 3494 3495 3496 3497
Aggregates are only allowed in select statements.
","
STDDEV(X)
"

"Functions (Aggregate)","VAR_POP","
3498
VAR_POP( [ DISTINCT ] numeric )
3499
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3500
","
3501 3502 3503 3504
The population variance (square of the population standard deviation).
This method returns a double.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3505 3506 3507 3508 3509
","
VAR_POP(X)
"

"Functions (Aggregate)","VAR_SAMP","
3510
VAR_SAMP( [ DISTINCT ] numeric )
3511
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3512
","
3513 3514 3515 3516
The sample variance (square of the sample standard deviation).
This method returns a double.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3517 3518 3519 3520
","
VAR_SAMP(X)
"

3521
"Functions (Aggregate)","MEDIAN","
3522
MEDIAN( [ DISTINCT ] value )
3523
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3524 3525 3526
","
The value separating the higher half of a values from the lower half.
Returns the middle value or an interpolated value between two middle values if number of values is even.
3527
Interpolation is only supported for numeric, date-time, and interval data types.
3528 3529 3530 3531 3532 3533 3534
NULL values are ignored in the calculation.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
MEDIAN(X)
"

3535
"Functions (Aggregate)","MODE","
3536 3537
{ MODE( value ) [ ORDER BY expression [ ASC | DESC ] ] }
    | { MODE() WITHIN GROUP(ORDER BY expression [ ASC | DESC ]) }
3538
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3539 3540 3541
","
Returns the value that occurs with the greatest frequency.
If there are multiple values with the same frequency only one value will be returned.
3542 3543 3544 3545 3546
In this situation value will be chosen based on optional ORDER BY clause
that should specify exactly the same expression as argument of this function.
Use ascending order to get smallest value or descending order to get largest value
from multiple values with the same frequency.
If this clause is not specified the exact chosen value is not determined in this situation.
3547 3548 3549 3550 3551
NULL values are ignored in the calculation.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
MODE(X)
3552
MODE(X ORDER BY X)
3553
MODE() WITHIN GROUP(ORDER BY X)
3554 3555
"

3556
"Functions (Aggregate)","ENVELOPE","
3557
ENVELOPE( value )
3558
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3559 3560 3561 3562 3563 3564 3565
","
Returns the minimum bounding box that encloses all specified GEOMETRY values.
Only 2D coordinate plane is supported.
NULL values are ignored in the calculation.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
3566
ENVELOPE(X)
3567 3568
"

Thomas Mueller's avatar
Thomas Mueller committed
3569
"Functions (Numeric)","ABS","
Thomas Mueller's avatar
Thomas Mueller committed
3570
ABS ( { numeric } )
Thomas Mueller's avatar
Thomas Mueller committed
3571
","
3572 3573
See also Java ""Math.abs"".
Please note that ""Math.abs(Integer.MIN_VALUE) == Integer.MIN_VALUE"" and ""Math.abs(Long.MIN_VALUE) == Long.MIN_VALUE"".
3574
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3575 3576 3577 3578 3579
","
ABS(ID)
"

"Functions (Numeric)","ACOS","
Thomas Mueller's avatar
Thomas Mueller committed
3580
ACOS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3581
","
Thomas Mueller's avatar
Thomas Mueller committed
3582 3583
Calculate the arc cosine.
See also Java ""Math.acos"".
3584
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3585 3586 3587 3588 3589
","
ACOS(D)
"

"Functions (Numeric)","ASIN","
Thomas Mueller's avatar
Thomas Mueller committed
3590
ASIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3591
","
Thomas Mueller's avatar
Thomas Mueller committed
3592 3593
Calculate the arc sine.
See also Java ""Math.asin"".
3594
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3595 3596 3597 3598 3599
","
ASIN(D)
"

"Functions (Numeric)","ATAN","
Thomas Mueller's avatar
Thomas Mueller committed
3600
ATAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3601
","
Thomas Mueller's avatar
Thomas Mueller committed
3602 3603
Calculate the arc tangent.
See also Java ""Math.atan"".
3604
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3605 3606 3607 3608 3609
","
ATAN(D)
"

"Functions (Numeric)","COS","
Thomas Mueller's avatar
Thomas Mueller committed
3610
COS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3611
","
Thomas Mueller's avatar
Thomas Mueller committed
3612 3613
Calculate the trigonometric cosine.
See also Java ""Math.cos"".
3614
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3615 3616 3617 3618
","
COS(ANGLE)
"

3619
"Functions (Numeric)","COSH","
Thomas Mueller's avatar
Thomas Mueller committed
3620
COSH(numeric)
3621 3622 3623 3624 3625 3626 3627 3628
","
Calculate the hyperbolic cosine.
See also Java ""Math.cosh"".
This method returns a double.
","
COSH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3629
"Functions (Numeric)","COT","
Thomas Mueller's avatar
Thomas Mueller committed
3630
COT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3631
","
Thomas Mueller's avatar
Thomas Mueller committed
3632
Calculate the trigonometric cotangent (""1/TAN(ANGLE)"").
3633
See also Java ""Math.*"" functions.
3634
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3635 3636 3637 3638 3639
","
COT(ANGLE)
"

"Functions (Numeric)","SIN","
Thomas Mueller's avatar
Thomas Mueller committed
3640
SIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3641
","
Thomas Mueller's avatar
Thomas Mueller committed
3642 3643
Calculate the trigonometric sine.
See also Java ""Math.sin"".
3644
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3645 3646 3647 3648
","
SIN(ANGLE)
"

3649
"Functions (Numeric)","SINH","
Thomas Mueller's avatar
Thomas Mueller committed
3650
SINH(numeric)
3651 3652 3653 3654 3655 3656 3657 3658
","
Calculate the hyperbolic sine.
See also Java ""Math.sinh"".
This method returns a double.
","
SINH(ANGLE)
"

Thomas Mueller's avatar
Thomas Mueller committed
3659
"Functions (Numeric)","TAN","
Thomas Mueller's avatar
Thomas Mueller committed
3660
TAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3661
","
Thomas Mueller's avatar
Thomas Mueller committed
3662 3663
Calculate the trigonometric tangent.
See also Java ""Math.tan"".
3664
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3665 3666 3667 3668
","
TAN(ANGLE)
"

3669
"Functions (Numeric)","TANH","
Thomas Mueller's avatar
Thomas Mueller committed
3670
TANH(numeric)
3671 3672 3673 3674 3675 3676 3677 3678
","
Calculate the hyperbolic tangent.
See also Java ""Math.tanh"".
This method returns a double.
","
TANH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3679
"Functions (Numeric)","ATAN2","
Thomas Mueller's avatar
Thomas Mueller committed
3680
ATAN2(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3681
","
Thomas Mueller's avatar
Thomas Mueller committed
3682
Calculate the angle when converting the rectangular coordinates to polar coordinates.
3683
See also Java ""Math.atan2"".
3684
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3685 3686 3687 3688 3689
","
ATAN2(X, Y)
"

"Functions (Numeric)","BITAND","
3690
BITAND(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3691
","
3692 3693
The bitwise AND operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3694 3695 3696 3697 3698
See also Java operator &.
","
BITAND(A, B)
"

3699 3700 3701 3702 3703 3704 3705 3706 3707 3708 3709
"Functions (Numeric)","BITGET","
BITGET(long, int)
","
Returns true if and only if the first parameter has a bit set in the
position specified by the second parameter.
This method returns a boolean.
The second parameter is zero-indexed; the least significant bit has position 0.
","
BITGET(A, 1)
"

Thomas Mueller's avatar
Thomas Mueller committed
3710
"Functions (Numeric)","BITOR","
3711
BITOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3712
","
3713 3714
The bitwise OR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3715 3716 3717 3718 3719 3720
See also Java operator |.
","
BITOR(A, B)
"

"Functions (Numeric)","BITXOR","
3721
BITXOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3722
","
3723 3724
The bitwise XOR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3725 3726 3727 3728 3729 3730
See also Java operator ^.
","
BITXOR(A, B)
"

"Functions (Numeric)","MOD","
3731
MOD(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3732
","
3733 3734
The modulo operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3735 3736 3737 3738 3739 3740
See also Java operator %.
","
MOD(A, B)
"

"Functions (Numeric)","CEILING","
Thomas Mueller's avatar
Thomas Mueller committed
3741
{ CEILING | CEIL } (numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3742
","
3743
See also Java ""Math.ceil"".
3744
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3745
","
3746
CEIL(A)
Thomas Mueller's avatar
Thomas Mueller committed
3747 3748 3749
"

"Functions (Numeric)","DEGREES","
Thomas Mueller's avatar
Thomas Mueller committed
3750
DEGREES(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3751
","
3752
See also Java ""Math.toDegrees"".
3753
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3754 3755 3756 3757 3758
","
DEGREES(A)
"

"Functions (Numeric)","EXP","
Thomas Mueller's avatar
Thomas Mueller committed
3759
EXP(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3760
","
3761
See also Java ""Math.exp"".
3762
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3763 3764 3765 3766 3767
","
EXP(A)
"

"Functions (Numeric)","FLOOR","
Thomas Mueller's avatar
Thomas Mueller committed
3768
FLOOR(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3769
","
3770
See also Java ""Math.floor"".
3771
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3772 3773 3774 3775 3776
","
FLOOR(A)
"

"Functions (Numeric)","LOG","
Thomas Mueller's avatar
Thomas Mueller committed
3777
{ LOG | LN } (numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3778
","
3779
See also Java ""Math.log"".
3780
In the PostgreSQL mode, LOG(x) is base 10.
3781
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3782 3783 3784 3785 3786
","
LOG(A)
"

"Functions (Numeric)","LOG10","
Thomas Mueller's avatar
Thomas Mueller committed
3787
LOG10(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3788
","
3789
See also Java ""Math.log10"".
3790
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3791 3792 3793 3794
","
LOG10(A)
"

3795 3796 3797 3798 3799 3800 3801 3802 3803 3804 3805 3806 3807
"Functions (Numeric)","ORA_HASH","
ORA_HASH(expression [, bucketLong [, seedLong]])
","
Computes a hash value.
Optional bucket argument determines the maximum returned value.
This argument should be between 0 and 4294967295, default is 4294967295.
Optional seed argument is combined with the given expression to return the different values for the same expression.
This argument should be between 0 and 4294967295, default is 0.
This method returns a long value between 0 and the specified or default bucket value inclusive.
","
ORA_HASH(A)
"

Thomas Mueller's avatar
Thomas Mueller committed
3808
"Functions (Numeric)","RADIANS","
Thomas Mueller's avatar
Thomas Mueller committed
3809
RADIANS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3810
","
3811
See also Java ""Math.toRadians"".
3812
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3813 3814 3815 3816 3817
","
RADIANS(A)
"

"Functions (Numeric)","SQRT","
Thomas Mueller's avatar
Thomas Mueller committed
3818
SQRT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3819
","
3820
See also Java ""Math.sqrt"".
3821
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3822 3823 3824 3825 3826
","
SQRT(A)
"

"Functions (Numeric)","PI","
3827
PI()
Thomas Mueller's avatar
Thomas Mueller committed
3828
","
3829
See also Java ""Math.PI"".
3830
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3831 3832 3833 3834 3835
","
PI()
"

"Functions (Numeric)","POWER","
Thomas Mueller's avatar
Thomas Mueller committed
3836
POWER(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3837
","
3838
See also Java ""Math.pow"".
Thomas Mueller's avatar
Thomas Mueller committed
3839
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3840 3841 3842 3843 3844
","
POWER(A, B)
"

"Functions (Numeric)","RAND","
3845
{ RAND | RANDOM } ( [ int ] )
Thomas Mueller's avatar
Thomas Mueller committed
3846 3847 3848
","
Calling the function without parameter returns the next a pseudo random number.
Calling it with an parameter seeds the session's random number generator.
Thomas Mueller's avatar
Thomas Mueller committed
3849
This method returns a double between 0 (including) and 1 (excluding).
Thomas Mueller's avatar
Thomas Mueller committed
3850 3851 3852 3853 3854
","
RAND()
"

"Functions (Numeric)","RANDOM_UUID","
3855
{ RANDOM_UUID | UUID } ()
Thomas Mueller's avatar
Thomas Mueller committed
3856 3857
","
Returns a new UUID with 122 pseudo random bits.
Thomas Mueller's avatar
Thomas Mueller committed
3858 3859 3860 3861 3862

Please note that using an index on randomly generated data will
result on poor performance once there are millions of rows in a table.
The reason is that the cache behavior is very bad with randomly distributed data.
This is a problem for any database system.
Thomas Mueller's avatar
Thomas Mueller committed
3863 3864 3865 3866 3867
","
RANDOM_UUID()
"

"Functions (Numeric)","ROUND","
3868
ROUND(numeric [, digitsInt])
Thomas Mueller's avatar
Thomas Mueller committed
3869
","
3870
Rounds to a number of digits, or to the nearest long if the number of digits if not set.
Thomas Mueller's avatar
Thomas Mueller committed
3871
This method returns a numeric (the same type as the input).
Thomas Mueller's avatar
Thomas Mueller committed
3872 3873 3874 3875 3876
","
ROUND(VALUE, 2)
"

"Functions (Numeric)","ROUNDMAGIC","
Thomas Mueller's avatar
Thomas Mueller committed
3877
ROUNDMAGIC(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3878
","
3879 3880 3881 3882 3883 3884
This function rounds numbers in a good way, but it is slow.
It has a special handling for numbers around 0.
Only numbers smaller or equal +/-1000000000000 are supported.
The value is converted to a String internally, and then the last last 4 characters are checked.
'000x' becomes '0000' and '999x' becomes '999999', which is rounded automatically.
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3885 3886 3887 3888 3889
","
ROUNDMAGIC(VALUE/3*3)
"

"Functions (Numeric)","SECURE_RAND","
3890
SECURE_RAND(int)
Thomas Mueller's avatar
Thomas Mueller committed
3891 3892
","
Generates a number of cryptographically secure random numbers.
3893
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3894 3895 3896 3897 3898
","
CALL SECURE_RAND(16)
"

"Functions (Numeric)","SIGN","
Thomas Mueller's avatar
Thomas Mueller committed
3899
SIGN ( { numeric } )
Thomas Mueller's avatar
Thomas Mueller committed
3900 3901 3902 3903 3904 3905 3906
","
Returns -1 if the value is smaller 0, 0 if zero, and otherwise 1.
","
SIGN(VALUE)
"

"Functions (Numeric)","ENCRYPT","
3907
ENCRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
3908
","
3909
Encrypts data using a key.
3910
The supported algorithm is AES.
3911 3912
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3913 3914 3915 3916 3917
","
CALL ENCRYPT('AES', '00', STRINGTOUTF8('Test'))
"

"Functions (Numeric)","DECRYPT","
3918
DECRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
3919
","
3920
Decrypts data using a key.
3921
The supported algorithm is AES.
3922 3923
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3924 3925 3926 3927 3928 3929
","
CALL TRIM(CHAR(0) FROM UTF8TOSTRING(
    DECRYPT('AES', '00', '3fabb4de8f1ee2e97d7793bab2db1116')))
"

"Functions (Numeric)","HASH","
3930
HASH(algorithmString, expression [, iterationInt])
Thomas Mueller's avatar
Thomas Mueller committed
3931
","
3932 3933 3934
Calculate the hash value using an algorithm, and repeat this process for a number of iterations.
Currently, the only algorithm supported is SHA256.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3935 3936 3937 3938 3939
","
CALL HASH('SHA256', STRINGTOUTF8('Password'), 1000)
"

"Functions (Numeric)","TRUNCATE","
3940 3941
{ TRUNC | TRUNCATE } ( { {numeric, digitsInt}
    | timestamp | timestampWithTimeZone | date | timestampString } )
Thomas Mueller's avatar
Thomas Mueller committed
3942 3943
","
Truncates to a number of digits (to the next value closer to 0).
3944
This method returns a double.
3945
When used with a timestamp, truncates a timestamp to a date (day) value.
3946 3947
When used with a date, truncates a date to a date (day) value less time part.
When used with a timestamp as string, truncates a timestamp to a date (day) value.
Thomas Mueller's avatar
Thomas Mueller committed
3948 3949 3950 3951 3952
","
TRUNCATE(VALUE, 2)
"

"Functions (Numeric)","COMPRESS","
3953
COMPRESS(dataBytes [, algorithmString])
Thomas Mueller's avatar
Thomas Mueller committed
3954
","
3955 3956 3957 3958
Compresses the data using the specified compression algorithm.
Supported algorithms are: LZF (faster but lower compression; default), and DEFLATE (higher compression).
Compression does not always reduce size. Very small objects and objects with little redundancy may get larger.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3959 3960 3961 3962 3963
","
COMPRESS(STRINGTOUTF8('Test'))
"

"Functions (Numeric)","EXPAND","
3964
EXPAND(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
3965 3966
","
Expands data that was compressed using the COMPRESS function.
3967
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
3968 3969 3970 3971 3972
","
UTF8TOSTRING(EXPAND(COMPRESS(STRINGTOUTF8('Test'))))
"

"Functions (Numeric)","ZERO","
3973
ZERO()
Thomas Mueller's avatar
Thomas Mueller committed
3974 3975 3976 3977 3978 3979 3980
","
Returns the value 0. This function can be used even if numeric literals are disabled.
","
ZERO()
"

"Functions (String)","ASCII","
3981
ASCII(string)
Thomas Mueller's avatar
Thomas Mueller committed
3982 3983
","
Returns the ASCII value of the first character in the string.
3984
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
3985 3986 3987 3988
","
ASCII('Hi')
"
"Functions (String)","BIT_LENGTH","
3989
BIT_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
3990
","
3991 3992 3993
Returns the number of bits in a string.
This method returns a long.
For BLOB, CLOB, BYTES and JAVA_OBJECT, the precision is used. Each character needs 16 bits.
Thomas Mueller's avatar
Thomas Mueller committed
3994 3995 3996 3997 3998
","
BIT_LENGTH(NAME)
"

"Functions (String)","LENGTH","
3999
{ LENGTH | CHAR_LENGTH | CHARACTER_LENGTH } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4000
","
4001 4002 4003
Returns the number of characters in a string.
This method returns a long.
For BLOB, CLOB, BYTES and JAVA_OBJECT, the precision is used.
Thomas Mueller's avatar
Thomas Mueller committed
4004 4005 4006 4007 4008
","
LENGTH(NAME)
"

"Functions (String)","OCTET_LENGTH","
4009
OCTET_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
4010
","
4011 4012 4013 4014
Returns the number of bytes in a string.
This method returns a long.
For BLOB, CLOB, BYTES and JAVA_OBJECT, the precision is used.
Each character needs 2 bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4015 4016 4017 4018 4019
","
OCTET_LENGTH(NAME)
"

"Functions (String)","CHAR","
4020
{ CHAR | CHR } ( int )
Thomas Mueller's avatar
Thomas Mueller committed
4021 4022
","
Returns the character that represents the ASCII value.
4023
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4024 4025 4026 4027 4028
","
CHAR(65)
"

"Functions (String)","CONCAT","
4029
CONCAT(string, string [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4030 4031
","
Combines strings.
Thomas Mueller's avatar
Thomas Mueller committed
4032
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
4033
and do not cause the result to become NULL.
4034
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4035 4036 4037 4038
","
CONCAT(NAME, '!')
"

4039 4040 4041 4042
"Functions (String)","CONCAT_WS","
CONCAT_WS(separatorString, string, string [,...])
","
Combines strings with separator.
Thomas Mueller's avatar
Thomas Mueller committed
4043
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
4044
and do not cause the result to become NULL.
4045 4046 4047 4048 4049
This method returns a string.
","
CONCAT_WS(',', NAME, '!')
"

Thomas Mueller's avatar
Thomas Mueller committed
4050
"Functions (String)","DIFFERENCE","
4051
DIFFERENCE(string, string)
Thomas Mueller's avatar
Thomas Mueller committed
4052 4053
","
Returns the difference between the sounds of two strings.
4054
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4055 4056 4057 4058 4059
","
DIFFERENCE(T1.NAME, T2.NAME)
"

"Functions (String)","HEXTORAW","
4060
HEXTORAW(string)
Thomas Mueller's avatar
Thomas Mueller committed
4061
","
4062 4063
Converts a hex representation of a string to a string.
4 hex characters per string character are used.
Thomas Mueller's avatar
Thomas Mueller committed
4064 4065 4066 4067 4068
","
HEXTORAW(DATA)
"

"Functions (String)","RAWTOHEX","
4069
RAWTOHEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
4070
","
4071 4072 4073
Converts a string to the hex representation.
4 hex characters per string character are used.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4074 4075 4076 4077 4078
","
RAWTOHEX(DATA)
"

"Functions (String)","INSTR","
4079
INSTR(string, searchString, [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
4080
","
4081
Returns the location of a search string in a string.
4082 4083 4084
If a start position is used, the characters before it are ignored.
If position is negative, the rightmost location is returned.
0 is returned if the search string is not found.
Thomas Mueller's avatar
Thomas Mueller committed
4085
Please note this function is case sensitive, even if the parameters are not.
Thomas Mueller's avatar
Thomas Mueller committed
4086 4087 4088 4089 4090
","
INSTR(EMAIL,'@')
"

"Functions (String)","INSERT Function","
4091
INSERT(originalString, startInt, lengthInt, addString)
Thomas Mueller's avatar
Thomas Mueller committed
4092
","
4093 4094 4095
Inserts a additional string into the original string at a specified start position.
The length specifies the number of characters that are removed at the start position in the original string.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4096 4097 4098 4099 4100
","
INSERT(NAME, 1, 1, ' ')
"

"Functions (String)","LOWER","
4101
{ LOWER | LCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4102 4103 4104 4105 4106 4107 4108
","
Converts a string to lowercase.
","
LOWER(NAME)
"

"Functions (String)","UPPER","
4109
{ UPPER | UCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4110 4111 4112 4113 4114 4115 4116
","
Converts a string to uppercase.
","
UPPER(NAME)
"

"Functions (String)","LEFT","
4117
LEFT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4118 4119 4120 4121 4122 4123 4124
","
Returns the leftmost number of characters.
","
LEFT(NAME, 3)
"

"Functions (String)","RIGHT","
4125
RIGHT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4126 4127 4128 4129 4130 4131 4132
","
Returns the rightmost number of characters.
","
RIGHT(NAME, 3)
"

"Functions (String)","LOCATE","
4133
LOCATE(searchString, string [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
4134
","
4135 4136 4137 4138
Returns the location of a search string in a string.
If a start position is used, the characters before it are ignored.
If position is negative, the rightmost location is returned.
0 is returned if the search string is not found.
Thomas Mueller's avatar
Thomas Mueller committed
4139 4140 4141 4142 4143
","
LOCATE('.', NAME)
"

"Functions (String)","POSITION","
4144
POSITION(searchString, string)
Thomas Mueller's avatar
Thomas Mueller committed
4145 4146 4147 4148 4149 4150 4151
","
Returns the location of a search string in a string. See also LOCATE.
","
POSITION('.', NAME)
"

"Functions (String)","LPAD","
4152
LPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
4153
","
4154 4155 4156
Left pad the string to the specified length.
If the length is shorter than the string, it will be truncated at the end.
If the padding string is not set, spaces will be used.
Thomas Mueller's avatar
Thomas Mueller committed
4157 4158 4159 4160 4161
","
LPAD(AMOUNT, 10, '*')
"

"Functions (String)","RPAD","
4162
RPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
4163
","
4164 4165 4166
Right pad the string to the specified length.
If the length is shorter than the string, it will be truncated.
If the padding string is not set, spaces will be used.
Thomas Mueller's avatar
Thomas Mueller committed
4167 4168 4169 4170 4171
","
RPAD(TEXT, 10, '-')
"

"Functions (String)","LTRIM","
4172
LTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
4173 4174 4175 4176 4177 4178 4179
","
Removes all leading spaces from a string.
","
LTRIM(NAME)
"

"Functions (String)","RTRIM","
4180
RTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
4181 4182 4183 4184 4185 4186 4187
","
Removes all trailing spaces from a string.
","
RTRIM(NAME)
"

"Functions (String)","TRIM","
4188
TRIM ( [ { LEADING | TRAILING | BOTH } [ string ] FROM ] string )
Thomas Mueller's avatar
Thomas Mueller committed
4189
","
4190 4191
Removes all leading spaces, trailing spaces, or spaces at both ends, from a string.
Other characters can be removed as well.
Thomas Mueller's avatar
Thomas Mueller committed
4192 4193 4194 4195 4196
","
TRIM(BOTH '_' FROM NAME)
"

"Functions (String)","REGEXP_REPLACE","
4197
REGEXP_REPLACE(inputString, regexString, replacementString [, flagsString])
Thomas Mueller's avatar
Thomas Mueller committed
4198
","
4199
Replaces each substring that matches a regular expression.
4200
For details, see the Java ""String.replaceAll()"" method.
4201 4202 4203 4204 4205 4206 4207 4208 4209 4210 4211 4212 4213 4214
If any parameter is null (except optional flagsString parameter), the result is null.

Flags values limited to 'i', 'c', 'n', 'm'. Other symbols causes exception.
Multiple symbols could be uses in one flagsString parameter (like 'im').
Later flags overrides first ones, for example 'ic' equivalent to case sensitive matching 'c'.

'i' enables case insensitive matching (Pattern.CASE_INSENSITIVE)

'c' disables case insensitive matching (Pattern.CASE_INSENSITIVE)

'n' allows the period to match the newline character (Pattern.DOTALL)

'm' enables multiline mode (Pattern.MULTILINE)

Thomas Mueller's avatar
Thomas Mueller committed
4215 4216
","
REGEXP_REPLACE('Hello    World', ' +', ' ')
4217
REGEXP_REPLACE('Hello WWWWorld', 'w+', 'W', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
4218 4219
"

4220 4221 4222 4223
"Functions (String)","REGEXP_LIKE","
REGEXP_LIKE(inputString, regexString [, flagsString])
","
Matches string to a regular expression.
4224 4225 4226 4227 4228 4229 4230 4231 4232 4233 4234 4235 4236 4237 4238
For details, see the Java ""Matcher.find()"" method.
If any parameter is null (except optional flagsString parameter), the result is null.

Flags values limited to 'i', 'c', 'n', 'm'. Other symbols causes exception.
Multiple symbols could be uses in one flagsString parameter (like 'im').
Later flags overrides first ones, for example 'ic' equivalent to case sensitive matching 'c'.

'i' enables case insensitive matching (Pattern.CASE_INSENSITIVE)

'c' disables case insensitive matching (Pattern.CASE_INSENSITIVE)

'n' allows the period to match the newline character (Pattern.DOTALL)

'm' enables multiline mode (Pattern.MULTILINE)

4239 4240
","
REGEXP_LIKE('Hello    World', '[A-Z ]*', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
4241 4242
"

4243

Thomas Mueller's avatar
Thomas Mueller committed
4244
"Functions (String)","REPEAT","
4245
REPEAT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4246 4247 4248 4249 4250 4251 4252
","
Returns a string repeated some number of times.
","
REPEAT(NAME || ' ', 10)
"

"Functions (String)","REPLACE","
4253
REPLACE(string, searchString [, replacementString])
Thomas Mueller's avatar
Thomas Mueller committed
4254
","
4255 4256
Replaces all occurrences of a search string in a text with another string.
If no replacement is specified, the search string is removed from the original string.
4257
If any parameter is null, the result is null.
Thomas Mueller's avatar
Thomas Mueller committed
4258 4259 4260 4261 4262
","
REPLACE(NAME, ' ')
"

"Functions (String)","SOUNDEX","
4263
SOUNDEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
4264
","
4265 4266 4267
Returns a four character code representing the sound of a string.
See also http://www.archives.gov/genealogy/census/soundex.html .
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4268 4269 4270 4271 4272
","
SOUNDEX(NAME)
"

"Functions (String)","SPACE","
4273
SPACE(int)
Thomas Mueller's avatar
Thomas Mueller committed
4274 4275 4276 4277 4278 4279 4280
","
Returns a string consisting of a number of spaces.
","
SPACE(80)
"

"Functions (String)","STRINGDECODE","
4281
STRINGDECODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
4282
","
4283 4284 4285
Converts a encoded string using the Java string literal encoding format.
Special characters are \b, \t, \n, \f, \r, \"", \\, \<octal>, \u<unicode>.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4286 4287 4288 4289 4290
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

"Functions (String)","STRINGENCODE","
4291
STRINGENCODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
4292
","
4293 4294 4295
Encodes special characters in a string using the Java string literal encoding format.
Special characters are \b, \t, \n, \f, \r, \"", \\, \<octal>, \u<unicode>.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4296 4297 4298 4299 4300
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

"Functions (String)","STRINGTOUTF8","
4301
STRINGTOUTF8(string)
Thomas Mueller's avatar
Thomas Mueller committed
4302 4303
","
Encodes a string to a byte array using the UTF8 encoding format.
4304
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4305 4306 4307 4308 4309
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","SUBSTRING","
4310
{ SUBSTRING | SUBSTR } ( string, startInt [, lengthInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
4311
","
4312
Returns a substring of a string starting at a position.
4313
If the start index is negative, then the start index is relative to the end of the string.
4314
The length is optional.
4315
Also supported is: ""SUBSTRING(string [FROM start] [FOR length])"".
Thomas Mueller's avatar
Thomas Mueller committed
4316
","
4317 4318
CALL SUBSTR('[Hello]', 2, 5);
CALL SUBSTR('Hello World', -5);
Thomas Mueller's avatar
Thomas Mueller committed
4319 4320 4321
"

"Functions (String)","UTF8TOSTRING","
4322
UTF8TOSTRING(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
4323 4324 4325 4326 4327 4328 4329
","
Decodes a byte array in the UTF8 format to a string.
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","XMLATTR","
4330
XMLATTR(nameString, valueString)
Thomas Mueller's avatar
Thomas Mueller committed
4331
","
4332
Creates an XML attribute element of the form ""name=value"".
4333 4334
The value is encoded as XML text.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4335 4336 4337 4338 4339
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'))
"

"Functions (String)","XMLNODE","
4340
XMLNODE(elementString [, attributesString [, contentString [, indentBoolean]]])
Thomas Mueller's avatar
Thomas Mueller committed
4341 4342
","
Create an XML node element.
4343 4344 4345
An empty or null attribute string means no attributes are set.
An empty or null content string means the node is empty.
The content is indented by default if it contains a newline.
4346
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4347 4348 4349 4350 4351
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'), 'H2')
"

"Functions (String)","XMLCOMMENT","
4352
XMLCOMMENT(commentString)
Thomas Mueller's avatar
Thomas Mueller committed
4353
","
4354
Creates an XML comment.
4355
Two dashes (""--"") are converted to ""- -"".
4356
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4357 4358 4359 4360 4361
","
CALL XMLCOMMENT('Test')
"

"Functions (String)","XMLCDATA","
4362
XMLCDATA(valueString)
Thomas Mueller's avatar
Thomas Mueller committed
4363
","
4364
Creates an XML CDATA element.
4365
If the value contains ""]]>"", an XML text element is created instead.
4366
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4367 4368 4369 4370 4371
","
CALL XMLCDATA('data')
"

"Functions (String)","XMLSTARTDOC","
4372
XMLSTARTDOC()
Thomas Mueller's avatar
Thomas Mueller committed
4373
","
Thomas Mueller's avatar
Thomas Mueller committed
4374
Returns the XML declaration.
4375
The result is always ""<?xml version=""1.0""?>"".
Thomas Mueller's avatar
Thomas Mueller committed
4376 4377 4378 4379 4380
","
CALL XMLSTARTDOC()
"

"Functions (String)","XMLTEXT","
4381
XMLTEXT(valueString [, escapeNewlineBoolean])
Thomas Mueller's avatar
Thomas Mueller committed
4382 4383
","
Creates an XML text element.
Thomas Mueller's avatar
Thomas Mueller committed
4384
If enabled, newline and linefeed is converted to an XML entity (&#).
4385
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4386 4387 4388 4389
","
CALL XMLTEXT('test')
"

4390
"Functions (String)","TO_CHAR","
4391
TO_CHAR(value [, formatString[, nlsParamString]])
4392 4393 4394 4395 4396 4397
","
Oracle-compatible TO_CHAR function that can format a timestamp, a number, or text.
","
CALL TO_CHAR(TIMESTAMP '2010-01-01 00:00:00', 'DD MON, YYYY')
"

4398
"Functions (String)","TRANSLATE","
4399
TRANSLATE(value, searchString, replacementString)
4400 4401 4402 4403 4404 4405
","
Oracle-compatible TRANSLATE function that replaces a sequence of characters in a string with another set of characters.
","
CALL TRANSLATE('Hello world', 'eo', 'EO')
"

Thomas Mueller's avatar
Thomas Mueller committed
4406
"Functions (Time and Date)","CURRENT_DATE","
4407
{ CURRENT_DATE [ () ] | CURDATE() | SYSDATE | TODAY }
Thomas Mueller's avatar
Thomas Mueller committed
4408 4409
","
Returns the current date.
4410
This method always returns the same value within a transaction.
Thomas Mueller's avatar
Thomas Mueller committed
4411 4412 4413 4414 4415
","
CURRENT_DATE()
"

"Functions (Time and Date)","CURRENT_TIME","
4416
{ CURRENT_TIME [ ( [ int ] ) ] | LOCALTIME [ ( [ int ] ) ] | CURTIME() }
Thomas Mueller's avatar
Thomas Mueller committed
4417 4418
","
Returns the current time.
4419 4420 4421 4422 4423
If fractional seconds precision is specified it should be from 0 to 9, 0 is default.
The specified value can be used only to limit precision of a result.
The actual maximum available precision depends on operating system and JVM and can be 3 (milliseconds) or higher.
Higher precision is not available before Java 9.
These methods always return the same value within a transaction.
Thomas Mueller's avatar
Thomas Mueller committed
4424 4425 4426 4427 4428
","
CURRENT_TIME()
"

"Functions (Time and Date)","CURRENT_TIMESTAMP","
4429 4430 4431 4432
CURRENT_TIMESTAMP [ ( [ int ] ) ]
","
Returns the current timestamp with time zone.
Time zone offset is set to a current time zone offset
4433
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
4434 4435 4436 4437 4438 4439 4440 4441 4442 4443
The specified value can be used only to limit precision of a result.
The actual maximum available precision depends on operating system and JVM and can be 3 (milliseconds) or higher.
Higher precision is not available before Java 9.
This method always returns the same value within a transaction.
","
CURRENT_TIMESTAMP()
"

"Functions (Time and Date)","LOCALTIMESTAMP","
{ LOCALTIMESTAMP [ ( [ int ] ) ] | NOW( [ int ] ) }
Thomas Mueller's avatar
Thomas Mueller committed
4444
","
4445
Returns the current timestamp.
4446
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
4447 4448 4449 4450
The specified value can be used only to limit precision of a result.
The actual maximum available precision depends on operating system and JVM and can be 3 (milliseconds) or higher.
Higher precision is not available before Java 9.
These methods always return the same value within a transaction.
Thomas Mueller's avatar
Thomas Mueller committed
4451
","
4452
LOCALTIMESTAMP()
Thomas Mueller's avatar
Thomas Mueller committed
4453 4454 4455
"

"Functions (Time and Date)","DATEADD","
4456
{ DATEADD| TIMESTAMPADD } (datetimeField, addIntLong, dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4457
","
4458
Adds units to a date-time value. The datetimeField indicates the unit.
4459
Use negative values to subtract units.
4460
addIntLong may be a long value when manipulating milliseconds,
4461
microseconds, or nanoseconds otherwise its range is restricted to int.
4462
This method returns a value with the same type as specified value if unit is compatible with this value.
4463 4464 4465
If specified field is a HOUR, MINUTE, SECOND, MILLISECOND, etc and value is a DATE value DATEADD returns combined TIMESTAMP.
Fields DAY, MONTH, YEAR, WEEK, etc are not allowed for TIME values.
Fields TIMEZONE_HOUR and TIMEZONE_MINUTE are only allowed for TIMESTAMP WITH TIME ZONE values.
Thomas Mueller's avatar
Thomas Mueller committed
4466 4467 4468 4469 4470
","
DATEADD('MONTH', 1, DATE '2001-01-31')
"

"Functions (Time and Date)","DATEDIFF","
4471
{ DATEDIFF | TIMESTAMPDIFF } (datetimeField, aDateAndTime, bDateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4472
","
4473
Returns the the number of crossed unit boundaries between two date/time values.
4474
This method returns a long.
4475
The datetimeField indicates the unit.
4476 4477
Only TIMEZONE_HOUR and TIMEZONE_MINUTE fields use the time zone offset component.
With all other fields if date/time values have time zone offset component it is ignored.
Thomas Mueller's avatar
Thomas Mueller committed
4478 4479 4480 4481 4482
","
DATEDIFF('YEAR', T1.CREATED, T2.CREATED)
"

"Functions (Time and Date)","DAYNAME","
4483
DAYNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4484 4485 4486 4487 4488 4489 4490
","
Returns the name of the day (in English).
","
DAYNAME(CREATED)
"

"Functions (Time and Date)","DAY_OF_MONTH","
4491
DAY_OF_MONTH(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4492 4493 4494 4495 4496 4497 4498
","
Returns the day of the month (1-31).
","
DAY_OF_MONTH(CREATED)
"

"Functions (Time and Date)","DAY_OF_WEEK","
4499
DAY_OF_WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4500 4501 4502 4503 4504 4505
","
Returns the day of the week (1 means Sunday).
","
DAY_OF_WEEK(CREATED)
"

4506 4507 4508 4509 4510 4511 4512 4513
"Functions (Time and Date)","ISO_DAY_OF_WEEK","
ISO_DAY_OF_WEEK(dateAndTime)
","
Returns the ISO day of the week (1 means Monday).
","
ISO_DAY_OF_WEEK(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4514
"Functions (Time and Date)","DAY_OF_YEAR","
4515
DAY_OF_YEAR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4516 4517 4518 4519 4520 4521 4522
","
Returns the day of the year (1-366).
","
DAY_OF_YEAR(CREATED)
"

"Functions (Time and Date)","EXTRACT","
4523
EXTRACT ( datetimeField FROM { dateAndTime | interval })
Thomas Mueller's avatar
Thomas Mueller committed
4524
","
4525
Returns a value of the specific time unit from a date/time value.
4526 4527
This method returns a numeric value with EPOCH field and
an int for all other fields.
Thomas Mueller's avatar
Thomas Mueller committed
4528 4529 4530 4531 4532
","
EXTRACT(SECOND FROM CURRENT_TIMESTAMP)
"

"Functions (Time and Date)","FORMATDATETIME","
4533
FORMATDATETIME ( dateAndTime, formatString
4534
[ , localeString [ , timeZoneString ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4535
","
4536 4537 4538
Formats a date, time or timestamp as a string.
The most important format characters are:
y year, M month, d day, H hour, m minute, s second.
4539
For details of the format, see ""java.text.SimpleDateFormat"".
4540 4541
timeZoneString may be specified if dateAndTime is a DATE, TIME or TIMESTAMP.
timeZoneString is ignored if dateAndTime is TIMESTAMP WITH TIME ZONE.
4542
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4543 4544 4545 4546 4547 4548
","
CALL FORMATDATETIME(TIMESTAMP '2001-02-03 04:05:06',
    'EEE, d MMM yyyy HH:mm:ss z', 'en', 'GMT')
"

"Functions (Time and Date)","HOUR","
4549
HOUR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4550
","
4551
Returns the hour (0-23) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4552 4553 4554 4555 4556
","
HOUR(CREATED)
"

"Functions (Time and Date)","MINUTE","
4557
MINUTE(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4558
","
4559
Returns the minute (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4560 4561 4562 4563 4564
","
MINUTE(CREATED)
"

"Functions (Time and Date)","MONTH","
4565
MONTH(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4566
","
4567
Returns the month (1-12) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4568 4569 4570 4571 4572
","
MONTH(CREATED)
"

"Functions (Time and Date)","MONTHNAME","
4573
MONTHNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4574 4575 4576 4577 4578 4579 4580
","
Returns the name of the month (in English).
","
MONTHNAME(CREATED)
"

"Functions (Time and Date)","PARSEDATETIME","
4581
PARSEDATETIME(string, formatString
4582
[, localeString [, timeZoneString]])
Thomas Mueller's avatar
Thomas Mueller committed
4583
","
4584 4585 4586
Parses a string and returns a timestamp.
The most important format characters are:
y year, M month, d day, H hour, m minute, s second.
4587
For details of the format, see ""java.text.SimpleDateFormat"".
Thomas Mueller's avatar
Thomas Mueller committed
4588 4589 4590 4591 4592 4593
","
CALL PARSEDATETIME('Sat, 3 Feb 2001 03:05:06 GMT',
    'EEE, d MMM yyyy HH:mm:ss z', 'en', 'GMT')
"

"Functions (Time and Date)","QUARTER","
4594
QUARTER(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4595
","
4596
Returns the quarter (1-4) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4597 4598 4599 4600 4601
","
QUARTER(CREATED)
"

"Functions (Time and Date)","SECOND","
4602
SECOND(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4603
","
4604
Returns the second (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4605 4606 4607 4608 4609
","
SECOND(CREATED)
"

"Functions (Time and Date)","WEEK","
4610
WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4611
","
4612
Returns the week (1-53) from a date/time value.
4613
This method uses the current system locale.
Thomas Mueller's avatar
Thomas Mueller committed
4614 4615 4616 4617
","
WEEK(CREATED)
"

4618
"Functions (Time and Date)","ISO_WEEK","
4619
ISO_WEEK(dateAndTime)
4620
","
4621
Returns the ISO week (1-53) from a date/time value.
4622
This function uses the ISO definition when
4623 4624 4625 4626 4627 4628
first week of year should have at least four days
and week is started with Monday.
","
ISO_WEEK(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4629
"Functions (Time and Date)","YEAR","
4630
YEAR(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4631
","
4632
Returns the year from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4633 4634 4635 4636
","
YEAR(CREATED)
"

4637
"Functions (Time and Date)","ISO_YEAR","
4638
ISO_YEAR(dateAndTime)
4639
","
4640
Returns the ISO week year from a date/time value.
4641 4642 4643 4644
","
ISO_YEAR(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4645
"Functions (System)","ARRAY_GET","
4646
ARRAY_GET(arrayExpression, indexExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4647 4648
","
Returns one element of an array.
4649
Returns NULL if there is no such element or array is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
4650 4651 4652 4653 4654
","
CALL ARRAY_GET(('Hello', 'World'), 2)
"

"Functions (System)","ARRAY_LENGTH","
Thomas Mueller's avatar
Thomas Mueller committed
4655
ARRAY_LENGTH(arrayExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4656 4657
","
Returns the length of an array.
4658
Returns NULL if the specified array is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
4659 4660 4661 4662
","
CALL ARRAY_LENGTH(('Hello', 'World'))
"

4663 4664 4665
"Functions (System)","ARRAY_CONTAINS","
ARRAY_CONTAINS(arrayExpression, value)
","
4666 4667
Returns a boolean TRUE if the array contains the value or FALSE if it does not contain it.
Returns NULL if the specified array is NULL.
4668 4669 4670 4671
","
CALL ARRAY_CONTAINS(('Hello', 'World'), 'Hello')
"

Thomas Mueller's avatar
Thomas Mueller committed
4672
"Functions (System)","AUTOCOMMIT","
4673
AUTOCOMMIT()
Thomas Mueller's avatar
Thomas Mueller committed
4674 4675 4676 4677 4678 4679 4680
","
Returns true if auto commit is switched on for this session.
","
AUTOCOMMIT()
"

"Functions (System)","CANCEL_SESSION","
4681
CANCEL_SESSION(sessionInt)
Thomas Mueller's avatar
Thomas Mueller committed
4682
","
4683 4684 4685
Cancels the currently executing statement of another session.
The method only works if the multithreaded kernel is enabled (see SET MULTI_THREADED).
Returns true if the statement was canceled, false if the session is closed or no statement is currently executing.
Thomas Mueller's avatar
Thomas Mueller committed
4686 4687

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4688 4689 4690 4691 4692
","
CANCEL_SESSION(3)
"

"Functions (System)","CASEWHEN Function","
4693
CASEWHEN(boolean, aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
4694 4695
","
Returns 'a' if the boolean expression is true, otherwise 'b'.
4696
Returns the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
4697 4698 4699 4700 4701
","
CASEWHEN(ID=1, 'A', 'B')
"

"Functions (System)","CAST","
4702
CAST(value AS dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4703
","
4704 4705 4706 4707 4708 4709 4710 4711 4712 4713 4714 4715
Converts a value to another data type. The following conversion rules are used:
When converting a number to a boolean, 0 is false and every other value is true.
When converting a boolean to a number, false is 0 and true is 1.
When converting a number to a number of another type, the value is checked for overflow.
When converting a number to binary, the number of bytes matches the precision.
When converting a string to binary, it is hex encoded (every byte two characters);
a hex string can be converted to a number by first converting it to binary.
If a direct conversion is not possible, the value is first converted to a string.
","
CAST(NAME AS INT);
CAST(65535 AS BINARY);
CAST(CAST('FFFF' AS BINARY) AS INT);
Thomas Mueller's avatar
Thomas Mueller committed
4716 4717 4718
"

"Functions (System)","COALESCE","
4719
{ COALESCE | NVL } (aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4720 4721 4722 4723 4724 4725 4726
","
Returns the first value that is not null.
","
COALESCE(A, B, C)
"

"Functions (System)","CONVERT","
4727
CONVERT(value, dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4728 4729 4730 4731 4732 4733 4734
","
Converts a value to another data type.
","
CONVERT(NAME, INT)
"

"Functions (System)","CURRVAL","
4735
CURRVAL( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
4736
","
4737 4738 4739 4740 4741
Returns the current (last) value of the sequence, independent of the session.
If the sequence was just created, the method returns (start - interval).
If the schema name is not set, the current schema is used.
If the schema name is not set, the sequence name is converted to uppercase (for compatibility).
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
4742 4743 4744 4745 4746
","
CURRVAL('TEST_SEQ')
"

"Functions (System)","CSVREAD","
4747
CSVREAD(fileNameString [, columnsString [, csvOptions ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4748
","
4749 4750
Returns the result set of reading the CSV (comma separated values) file.
For each parameter, NULL means the default value should be used.
Thomas Mueller's avatar
Thomas Mueller committed
4751 4752

If the column names are specified (a list of column names separated with the
4753
fieldSeparator), those are used, otherwise (or if they are set to NULL) the first line of
4754 4755 4756 4757 4758
the file is interpreted as the column names.
In that case, column names that contain no special characters (only letters, '_',
and digits; similar to the rule for Java identifiers) are considered case insensitive.
Other column names are case sensitive, that means you need to use quoted identifiers
(see below).
Thomas Mueller's avatar
Thomas Mueller committed
4759 4760 4761 4762 4763

The default charset is the default value for this system, and the default field separator
is a comma. Missing unquoted values as well as data that matches nullString is
parsed as NULL. All columns of type VARCHAR.

4764 4765
The BOM (the byte-order-mark) character 0xfeff at the beginning of the file is ignored.

4766
This function can be used like a table: ""SELECT * FROM CSVREAD(...)"".
4767

Thomas Mueller's avatar
Thomas Mueller committed
4768
Instead of a file, an URL may be used, for example
4769 4770
""jar:file:///c:/temp/example.zip!/org/example/nested.csv"".
To read a stream from the classpath, use the prefix ""classpath:"".
Thomas Mueller's avatar
Thomas Mueller committed
4771
To read from HTTP, use the prefix ""http:"" (as in a browser).
4772

Thomas Mueller's avatar
Thomas Mueller committed
4773 4774 4775
For performance reason, CSVREAD should not be used inside a join.
Instead, import the data first (possibly into a temporary table) and then use the table.

Thomas Mueller's avatar
Thomas Mueller committed
4776 4777 4778 4779
Admin rights are required to execute this command.
","
CALL CSVREAD('test.csv');
-- Read a file containing the columns ID, NAME with
Thomas Mueller's avatar
Thomas Mueller committed
4780 4781 4782 4783
CALL CSVREAD('test2.csv', 'ID|NAME', 'charset=UTF-8 fieldSeparator=|');
SELECT * FROM CSVREAD('data/test.csv', null, 'rowSeparator=;');
-- Read a tab-separated file
SELECT * FROM CSVREAD('data/test.tsv', null, 'rowSeparator=' || CHAR(9));
Thomas Mueller's avatar
Thomas Mueller committed
4784
SELECT ""Last Name"" FROM CSVREAD('address.csv');
4785
SELECT ""Last Name"" FROM CSVREAD('classpath:/org/acme/data/address.csv');
Thomas Mueller's avatar
Thomas Mueller committed
4786 4787 4788
"

"Functions (System)","CSVWRITE","
4789
CSVWRITE ( fileNameString, queryString [, csvOptions [, lineSepString] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4790
","
4791
Writes a CSV (comma separated values). The file is overwritten if it exists.
Thomas Mueller's avatar
Thomas Mueller committed
4792
If only a file name is specified, it will be written to the current working directory.
4793
For each parameter, NULL means the default value should be used.
Thomas Mueller's avatar
Thomas Mueller committed
4794
The default charset is the default value for this system, and the default field separator is a comma.
Thomas Mueller's avatar
Thomas Mueller committed
4795 4796 4797 4798 4799

The values are converted to text using the default string representation;
if another conversion is required you need to change the select statement accordingly.
The parameter nullString is used when writing NULL (by default nothing is written
when NULL appears). The default line separator is the default value for this
4800
system (system property ""line.separator"").
Thomas Mueller's avatar
Thomas Mueller committed
4801

Thomas Mueller's avatar
Thomas Mueller committed
4802 4803
The returned value is the number or rows written.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4804
","
Thomas Mueller's avatar
Thomas Mueller committed
4805 4806 4807 4808
CALL CSVWRITE('data/test.csv', 'SELECT * FROM TEST');
CALL CSVWRITE('data/test2.csv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=|');
-- Write a tab-separated file
CALL CSVWRITE('data/test.tsv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=' || CHAR(9));
Thomas Mueller's avatar
Thomas Mueller committed
4809 4810 4811
"

"Functions (System)","DATABASE","
4812
DATABASE()
Thomas Mueller's avatar
Thomas Mueller committed
4813 4814 4815 4816 4817 4818 4819
","
Returns the name of the database.
","
CALL DATABASE();
"

"Functions (System)","DATABASE_PATH","
4820
DATABASE_PATH()
Thomas Mueller's avatar
Thomas Mueller committed
4821
","
Thomas Mueller's avatar
Thomas Mueller committed
4822 4823
Returns the directory of the database files and the database name, if it is file based.
Returns NULL otherwise.
Thomas Mueller's avatar
Thomas Mueller committed
4824 4825 4826 4827
","
CALL DATABASE_PATH();
"

4828
"Functions (System)","DECODE","
Thomas Mueller's avatar
Thomas Mueller committed
4829
DECODE(value, whenValue, thenValue [,...])
4830 4831 4832 4833 4834 4835 4836 4837
","
Returns the first matching value. NULL is considered to match NULL.
If no match was found, then NULL or the last parameter (if the parameter count is even) is returned.
This function is provided for Oracle compatibility (see there for details).
","
CALL DECODE(RAND()>0.5, 0, 'Red', 1, 'Black');
"

4838
"Functions (System)","DISK_SPACE_USED","
Thomas Mueller's avatar
Thomas Mueller committed
4839
DISK_SPACE_USED(tableNameString)
4840 4841 4842 4843 4844 4845 4846 4847
","
Returns the approximate amount of space used by the table specified.
Does not currently take into account indexes or LOB's.
This function may be expensive since it has to load every page in the table.
","
CALL DISK_SPACE_USED('my_table');
"

4848
"Functions (System)","SIGNAL","
4849
SIGNAL(sqlStateString, messageString)
4850 4851 4852 4853 4854 4855
","
Throw an SQLException with the passed SQLState and reason.
","
CALL SIGNAL('23505', 'Duplicate user ID: ' || user_id);
"

4856 4857 4858 4859 4860 4861 4862 4863 4864 4865 4866 4867 4868 4869 4870 4871 4872
"Functions (System)","ESTIMATED_ENVELOPE","
ESTIMATED_ENVELOPE(tableNameString, columnNameString)
","
Returns the estimated minimum bounding box that encloses all specified GEOMETRY values.
Only 2D coordinate plane is supported.
NULL values are ignored.
This function is only supported by MVStore engine.
Column must have a spatial index.
This function is fast, but estimation may include uncommitted data (including data from other transactions),
may return approximate bounds, or be different with actual value due to other reasons.
Use with caution.
If estimation is not available this function returns NULL.
For accurate and reliable result use ESTIMATE aggregate function instead.
","
CALL ESTIMATED_ENVELOPE('MY_TABLE', 'GEOMETRY_COLUMN');
"

Thomas Mueller's avatar
Thomas Mueller committed
4873
"Functions (System)","FILE_READ","
4874
FILE_READ(fileNameString [,encodingString])
Thomas Mueller's avatar
Thomas Mueller committed
4875 4876 4877 4878
","
Returns the contents of a file. If only one parameter is supplied, the data are
returned as a BLOB. If two parameters are used, the data is returned as a CLOB
(text). The second parameter is the character set to use, NULL meaning the
4879
default character set for this system.
4880 4881 4882 4883

File names and URLs are supported.
To read a stream from the classpath, use the prefix ""classpath:"".

Thomas Mueller's avatar
Thomas Mueller committed
4884
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4885 4886 4887 4888 4889
","
SELECT LENGTH(FILE_READ('~/.h2.server.properties')) LEN;
SELECT FILE_READ('http://localhost:8182/stylesheet.css', NULL) CSS;
"

4890
"Functions (System)","FILE_WRITE","
4891
FILE_WRITE(blobValue, fileNameString)
4892 4893 4894 4895 4896 4897 4898 4899
","
Write the supplied parameter into a file. Return the number of bytes written.

Write access to folder, and admin rights are required to execute this command.
","
SELECT FILE_WRITE('Hello world', '/tmp/hello.txt')) LEN;
"

Thomas Mueller's avatar
Thomas Mueller committed
4900
"Functions (System)","GREATEST","
4901
GREATEST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4902 4903 4904 4905 4906 4907 4908
","
Returns the largest value that is not NULL, or NULL if all values are NULL.
","
CALL GREATEST(1, 2, 3);
"

"Functions (System)","IDENTITY","
4909
IDENTITY()
Thomas Mueller's avatar
Thomas Mueller committed
4910 4911
","
Returns the last inserted identity value for this session.
4912
This value changes whenever a new sequence number was generated,
4913
even within a trigger or Java function. See also SCOPE_IDENTITY.
4914
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
4915 4916 4917 4918 4919
","
CALL IDENTITY();
"

"Functions (System)","IFNULL","
4920
IFNULL(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
4921 4922 4923 4924 4925 4926 4927
","
Returns the value of 'a' if it is not null, otherwise 'b'.
","
CALL IFNULL(NULL, '');
"

"Functions (System)","LEAST","
4928
LEAST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4929 4930 4931 4932 4933 4934 4935
","
Returns the smallest value that is not NULL, or NULL if all values are NULL.
","
CALL LEAST(1, 2, 3);
"

"Functions (System)","LOCK_MODE","
4936
LOCK_MODE()
Thomas Mueller's avatar
Thomas Mueller committed
4937 4938
","
Returns the current lock mode. See SET LOCK_MODE.
4939
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4940 4941 4942 4943 4944
","
CALL LOCK_MODE();
"

"Functions (System)","LOCK_TIMEOUT","
4945
LOCK_TIMEOUT()
Thomas Mueller's avatar
Thomas Mueller committed
4946 4947 4948 4949 4950 4951 4952 4953
","
Returns the lock timeout of the current session (in milliseconds).
","
LOCK_TIMEOUT()
"

"Functions (System)","LINK_SCHEMA","
LINK_SCHEMA(targetSchemaString, driverString, urlString,
4954
userString, passwordString, sourceSchemaString)
Thomas Mueller's avatar
Thomas Mueller committed
4955
","
4956 4957 4958 4959 4960
Creates table links for all tables in a schema.
If tables with the same name already exist, they are dropped first.
The target schema is created automatically if it does not yet exist.
The driver name may be empty if the driver is already loaded.
The list of tables linked is returned in the form of a result set.
Thomas Mueller's avatar
Thomas Mueller committed
4961
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4962 4963 4964 4965 4966
","
CALL LINK_SCHEMA('TEST2', '', 'jdbc:h2:test2', 'sa', 'sa', 'PUBLIC');
"

"Functions (System)","MEMORY_FREE","
4967
MEMORY_FREE()
Thomas Mueller's avatar
Thomas Mueller committed
4968
","
Thomas Mueller's avatar
Thomas Mueller committed
4969
Returns the free memory in KB (where 1024 bytes is a KB).
4970
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4971 4972
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4973 4974 4975 4976 4977
","
MEMORY_FREE()
"

"Functions (System)","MEMORY_USED","
4978
MEMORY_USED()
Thomas Mueller's avatar
Thomas Mueller committed
4979
","
Thomas Mueller's avatar
Thomas Mueller committed
4980
Returns the used memory in KB (where 1024 bytes is a KB).
4981
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4982 4983
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4984 4985 4986 4987 4988
","
MEMORY_USED()
"

"Functions (System)","NEXTVAL","
4989
NEXTVAL ( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
4990
","
4991 4992 4993 4994
Returns the next value of the sequence.
Used values are never re-used, even when the transaction is rolled back.
If the schema name is not set, the current schema is used, and the sequence name is converted to uppercase (for compatibility).
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
4995 4996 4997 4998 4999
","
NEXTVAL('TEST_SEQ')
"

"Functions (System)","NULLIF","
5000
NULLIF(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
5001 5002 5003 5004 5005 5006
","
Returns NULL if 'a' is equals to 'b', otherwise 'a'.
","
NULLIF(A, B)
"

5007 5008 5009 5010
"Functions (System)","NVL2","
NVL2(testValue, aValue, bValue)
","
If the test value is null, then 'b' is returned. Otherwise, 'a' is returned.
5011
The data type of the returned value is the data type of 'a' if this is a text type.
5012 5013 5014 5015
","
NVL2(X, 'not null', 'null')
"

Thomas Mueller's avatar
Thomas Mueller committed
5016
"Functions (System)","READONLY","
5017
READONLY()
Thomas Mueller's avatar
Thomas Mueller committed
5018 5019 5020 5021 5022 5023 5024
","
Returns true if the database is read-only.
","
READONLY()
"

"Functions (System)","ROWNUM","
5025
ROWNUM()
Thomas Mueller's avatar
Thomas Mueller committed
5026
","
5027
Returns the number of the current row.
5028
This method returns an integer value.
5029
It is supported for SELECT statements, as well as for DELETE and UPDATE.
5030
The first row has the row number 1, and is calculated before ordering and grouping the result set,
5031
but after evaluating index conditions (even when the index conditions are specified in an outer query).
5032
Use the ROW_NUMBER() OVER () function to get row numbers after grouping or in specified order.
Thomas Mueller's avatar
Thomas Mueller committed
5033
","
5034 5035
SELECT ROWNUM(), * FROM TEST;
SELECT ROWNUM(), * FROM (SELECT * FROM TEST ORDER BY NAME);
Thomas Mueller's avatar
Thomas Mueller committed
5036
SELECT ID FROM (SELECT T.*, ROWNUM AS R FROM TEST T) WHERE R BETWEEN 2 AND 3;
Thomas Mueller's avatar
Thomas Mueller committed
5037 5038 5039
"

"Functions (System)","SCHEMA","
5040
SCHEMA()
Thomas Mueller's avatar
Thomas Mueller committed
5041
","
5042
Returns the name of the default schema for this session.
Thomas Mueller's avatar
Thomas Mueller committed
5043 5044 5045 5046
","
CALL SCHEMA()
"

5047 5048 5049
"Functions (System)","SCOPE_IDENTITY","
SCOPE_IDENTITY()
","
5050
Returns the last inserted identity value for this session for the current scope
5051
(the current statement).
5052 5053 5054 5055 5056 5057
Changes within triggers and Java functions are ignored. See also IDENTITY().
This method returns a long.
","
CALL SCOPE_IDENTITY();
"

Thomas Mueller's avatar
Thomas Mueller committed
5058
"Functions (System)","SESSION_ID","
5059
SESSION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
5060
","
5061 5062 5063 5064
Returns the unique session id number for the current database connection.
This id stays the same while the connection is open.
This method returns an int.
The database engine may re-use a session id after the connection is closed.
Thomas Mueller's avatar
Thomas Mueller committed
5065 5066 5067 5068 5069
","
CALL SESSION_ID()
"

"Functions (System)","SET","
5070
SET(@variableName, value)
Thomas Mueller's avatar
Thomas Mueller committed
5071
","
5072 5073 5074
Updates a variable with the given value.
The new value is returned.
When used in a query, the value is updated in the order the rows are read.
Thomas Mueller's avatar
Thomas Mueller committed
5075
When used in a subquery, not all rows might be read depending on the query plan.
Thomas Mueller's avatar
Thomas Mueller committed
5076
This can be used to implement running totals / cumulative sums.
Thomas Mueller's avatar
Thomas Mueller committed
5077 5078 5079 5080 5081
","
SELECT X, SET(@I, IFNULL(@I, 0)+X) RUNNING_TOTAL FROM SYSTEM_RANGE(1, 10)
"

"Functions (System)","TABLE","
5082
{ TABLE | TABLE_DISTINCT } ( { name dataType = expression } [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
5083 5084 5085 5086 5087 5088 5089
","
Returns the result set. TABLE_DISTINCT removes duplicate rows.
","
SELECT * FROM TABLE(ID INT=(1, 2), NAME VARCHAR=('Hello', 'World'))
"

"Functions (System)","TRANSACTION_ID","
5090
TRANSACTION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
5091
","
5092 5093
Returns the current transaction id for this session.
This method returns NULL if there is no uncommitted change, or if the the database is not persisted.
Thomas Mueller's avatar
Thomas Mueller committed
5094
Otherwise a value of the following form is returned:
5095
""logFileId-position-sessionId"".
5096 5097
This method returns a string.
The value is unique across database restarts (values are not re-used).
Thomas Mueller's avatar
Thomas Mueller committed
5098 5099 5100 5101
","
CALL TRANSACTION_ID()
"

5102 5103 5104 5105 5106 5107 5108 5109 5110 5111 5112 5113
"Functions (System)","TRUNCATE_VALUE","
TRUNCATE_VALUE(value, precisionInt, forceBoolean)
","
Truncate a value to the required precision.
The precision of the returned value may be a bit larger than requested,
because fixed precision values are not truncated (unlike the numeric TRUNCATE method).
Unlike CAST, the truncating a decimal value may lose precision if the force flag is set to true.
The method returns a value with the same data type as the first parameter.
","
CALL TRUNCATE_VALUE(X, 10, TRUE);
"

Thomas Mueller's avatar
Thomas Mueller committed
5114
"Functions (System)","USER","
5115
{ USER | CURRENT_USER } ()
Thomas Mueller's avatar
Thomas Mueller committed
5116 5117 5118 5119 5120 5121
","
Returns the name of the current user of this session.
","
CURRENT_USER()
"

5122 5123 5124 5125 5126 5127 5128 5129
"Functions (System)","H2VERSION","
H2VERSION()
","
Returns the H2 version as a String.
","
H2VERSION()
"

5130
"Functions (Window)","ROW_NUMBER","
5131
ROW_NUMBER() OVER windowNameOrSpecification
5132 5133 5134 5135 5136 5137 5138 5139 5140 5141 5142 5143
","
Returns the number of the current row starting with 1.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT ROW_NUMBER() OVER (), * FROM TEST;
SELECT ROW_NUMBER() OVER (ORDER BY ID), * FROM TEST;
SELECT ROW_NUMBER() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","RANK","
5144
RANK() OVER windowNameOrSpecification
5145 5146 5147 5148 5149 5150 5151 5152 5153 5154 5155 5156 5157 5158
","
Returns the rank of the current row.
The rank of a row is the number of rows that precede this row plus 1.
If two or more rows have the same values in ORDER BY columns, these rows get the same rank from the first row with the same values.
It means that gaps in ranks are possible.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","DENSE_RANK","
5159
DENSE_RANK() OVER windowNameOrSpecification
5160 5161 5162 5163 5164 5165 5166 5167 5168
","
Returns the dense rank of the current row.
The rank of a row is the number of groups of rows with the same values in ORDER BY columns that precede group with this row plus 1.
If two or more rows have the same values in ORDER BY columns, these rows get the same rank.
Gaps in ranks are not possible.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
5169 5170 5171 5172 5173
SELECT DENSE_RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT DENSE_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","PERCENT_RANK","
5174
PERCENT_RANK() OVER windowNameOrSpecification
5175 5176 5177 5178 5179 5180 5181 5182 5183 5184 5185 5186 5187
","
Returns the relative rank of the current row.
The relative rank is calculated as (RANK - 1) / (NR - 1),
where RANK is a rank of the row and NR is a number of rows in window partition with this row.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT PERCENT_RANK() OVER (ORDER BY ID), * FROM TEST;
SELECT PERCENT_RANK() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","CUME_DIST","
5188
CUME_DIST() OVER windowNameOrSpecification
5189 5190 5191 5192 5193 5194 5195 5196 5197 5198 5199
","
Returns the relative rank of the current row.
The relative rank is calculated as NP / NR
where NP is a number of rows that precede the current row or have the same values in ORDER BY columns
and NR is a number of rows in window partition with this row.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT CUME_DIST() OVER (ORDER BY ID), * FROM TEST;
SELECT CUME_DIST() OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
5200 5201
"

5202
"Functions (Window)","NTILE","
5203
NTILE(int) OVER windowNameOrSpecification
5204 5205 5206 5207 5208 5209 5210 5211 5212 5213 5214 5215 5216 5217
","
Distributes the rows into a specified number of groups.
Number of groups should be a positive integer value.
NTILE returns the 1-based number of the group to which the current row belongs.
First groups will have more rows if number of rows is not divisible by number of groups.
For example, if 5 rows are distributed into 2 groups this function returns 1 for the first 3 row and 2 for the last 2 rows.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT NTILE(10) OVER (ORDER BY ID), * FROM TEST;
SELECT NTILE(5) OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

5218 5219
"Functions (Window)","LEAD","
LEAD(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
5220
OVER windowNameOrSpecification
5221 5222 5223 5224 5225 5226 5227 5228 5229 5230 5231 5232 5233 5234 5235 5236 5237 5238 5239
","
Returns the value in a next row with specified offset relative to the current row.
Offset must be non-negative.
If IGNORE NULLS is specified rows with null values in selected expression are skipped.
If number of considered rows is less than specified relative number this function returns NULL
or the specified default value, if any.
If offset is 0 the value from the current row is returned unconditionally.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT LEAD(X) OVER (ORDER BY ID), * FROM TEST;
SELECT LEAD(X, 2, 0) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
), * FROM TEST;
"

"Functions (Window)","LAG","
LAG(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
5240
OVER windowNameOrSpecification
5241 5242 5243 5244 5245 5246 5247 5248 5249 5250 5251 5252 5253 5254 5255 5256 5257
","
Returns the value in a previous row with specified offset relative to the current row.
Offset must be non-negative.
If IGNORE NULLS is specified rows with null values in selected expression are skipped.
If number of considered rows is less than specified relative number this function returns NULL
or the specified default value, if any.
If offset is 0 the value from the current row is returned unconditionally.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT LAG(X) OVER (ORDER BY ID), * FROM TEST;
SELECT LAG(X, 2, 0) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
), * FROM TEST;
"

5258
"Functions (Window)","FIRST_VALUE","
5259 5260
FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
5261 5262 5263 5264 5265 5266 5267 5268 5269 5270 5271 5272
","
Returns the first value in a window.
If IGNORE NULLS is specified null values are skipped and the function returns first non-null value, if any.

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT FIRST_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
SELECT FIRST_VALUE(X) IGNORE NULLS OVER (PARTITION BY CATEGORY ORDER BY ID), * FROM TEST;
"

"Functions (Window)","LAST_VALUE","
5273 5274
LAST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
5275 5276 5277 5278
","
Returns the last value in a window.
If IGNORE NULLS is specified null values are skipped and the function returns last non-null value before them, if any;
if there is no non-null value it returns NULL.
5279
Note that the last value is actually a value in the current row if window frame is not specified.
5280 5281 5282 5283 5284

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT LAST_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
5285 5286 5287 5288
SELECT LAST_VALUE(X) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
    RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
), * FROM TEST;
5289 5290 5291
"

"Functions (Window)","NTH_VALUE","
5292
NTH_VALUE(value, nInt) [FROM {FIRST|LAST}] [{RESPECT|IGNORE} NULLS]
5293
OVER windowNameOrSpecification
5294 5295 5296
","
Returns the value in a row with a specified relative number in a window.
Relative row number must be positive.
5297
If FROM LAST is specified rows a counted backwards from the last row.
5298 5299
If IGNORE NULLS is specified rows with null values in selected expression are skipped.
If number of considered rows is less than specified relative number this function returns NULL.
5300
Note that the last row is actually a current row if window frame is not specified.
5301 5302 5303 5304 5305

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
SELECT NTH_VALUE(X) OVER (ORDER BY ID), * FROM TEST;
5306 5307 5308 5309
SELECT NTH_VALUE(X) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
    RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
), * FROM TEST;
5310 5311
"

Thomas Mueller's avatar
Thomas Mueller committed
5312 5313 5314 5315 5316 5317 5318 5319 5320 5321 5322 5323 5324 5325 5326
"System Tables","Information Schema","
INFORMATION_SCHEMA
","
To get the list of system tables, execute the statement SELECT * FROM
INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'INFORMATION_SCHEMA'
","

"
"System Tables","Range Table","
SYSTEM_RANGE(start, end)
","
Contains all values from start to end (this is a dynamic table).
","
SYSTEM_RANGE(0, 100)
"
Thomas Mueller's avatar
Thomas Mueller committed
5327