help.csv 172.3 KB
Newer Older
1
# Copyright 2004-2019 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
GROUP BY groups the result by the given expression(s).
22
HAVING filters rows after grouping.
23 24
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 or rows are locked for writing.
This clause is not allowed in DISTINCT queries and in queries with non-window aggregates, GROUP BY, or HAVING clauses.
44 45
When using default MVStore engine only the selected rows are locked as in an UPDATE statement;
locking behavior for rows that were excluded from result using OFFSET / FETCH is undefined.
46
With PageStore engine the whole tables are locked.
Thomas Mueller's avatar
Thomas Mueller committed
47 48
","
SELECT * FROM TEST;
49 50 51 52
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;
53 54
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
55 56 57
SELECT * FROM (SELECT ID, COUNT(*) FROM TEST
    GROUP BY ID UNION SELECT NULL, COUNT(*) FROM TEST)
    ORDER BY 1 NULLS LAST;
58 59
SELECT DISTINCT C1, C2 FROM TEST;
SELECT DISTINCT ON(C1) C1, C2 FROM TEST ORDER BY C1;
Thomas Mueller's avatar
Thomas Mueller committed
60 61 62
"

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

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
70 71 72 73 74
","
INSERT INTO TEST VALUES(1, 'Hello')
"

"Commands (DML)","UPDATE","
75
UPDATE tableName [ [ AS ] newTableAlias ] SET setClauseList
76
[ WHERE expression ] [ ORDER BY order [,...] ] [ LIMIT expression ]
Thomas Mueller's avatar
Thomas Mueller committed
77 78
","
Updates data in a table.
79
ORDER BY is supported for MySQL compatibility, but it is ignored.
Thomas Mueller's avatar
Thomas Mueller committed
80
","
81 82
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
83 84 85
"

"Commands (DML)","DELETE","
86
DELETE [ TOP term ] FROM tableName [ WHERE expression ] [ LIMIT term ]
Thomas Mueller's avatar
Thomas Mueller committed
87 88
","
Deletes rows form a table.
89
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
90 91 92 93 94 95 96
","
DELETE FROM TEST WHERE ID=2
"

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

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

"Commands (DML)","EXPLAIN","
115 116
EXPLAIN { [ PLAN FOR ] | ANALYZE }
{ select | insert | update | delete | merge }
Thomas Mueller's avatar
Thomas Mueller committed
117 118
","
Shows the execution plan for a statement.
119 120
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
121 122 123 124 125
","
EXPLAIN SELECT * FROM TEST WHERE ID=1
"

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

Owner's avatar
Owner committed
137
"Commands (DML)","MERGE USING","
138 139
MERGE INTO targetTableName [ [AS] targetAlias]
USING { ( select ) | sourceTableName }[ [AS] sourceAlias ]
140
ON expression
141 142 143 144 145 146 147 148
mergeWhenClause [,...]
","
Updates or deletes existing rows, and insert rows that don't exist.

The ON clause specifies the matching column expression.
Different rows from a source table may not match with the same target row,
but one source row may be matched with multiple target rows.

149
If statement doesn't need a source table a DUAL table can be substituted.
Owner's avatar
Owner committed
150
","
151
MERGE INTO TARGET_TABLE AS T USING SOURCE_TABLE AS S
152
    ON T.ID = S.ID
153 154 155 156
    WHEN MATCHED AND T.COL2 <> 'FINAL' THEN
        UPDATE SET T.COL1 = S.COL1
    WHEN MATCHED AND T.COL2 = 'FINAL' THEN
        DELETE
157
    WHEN NOT MATCHED THEN
158
        INSERT (ID, COL1, COL2) VALUES(S.ID, S.COL1, S.COL2)
159
MERGE INTO TARGET_TABLE AS T USING (SELECT * FROM SOURCE_TABLE) AS S
160
    ON T.ID = S.ID
161 162 163 164
    WHEN MATCHED AND T.COL2 <> 'FINAL' THEN
        UPDATE SET T.COL1 = S.COL1
    WHEN MATCHED AND T.COL2 = 'FINAL' THEN
        DELETE
165
    WHEN NOT MATCHED THEN
166
        INSERT VALUES (S.ID, S.COL1, S.COL2)
167
MERGE INTO TARGET_TABLE USING DUAL ON ID = 1
168
    WHEN NOT MATCHED THEN INSERT VALUES (1, 'Test')
169
    WHEN MATCHED THEN UPDATE SET NAME = 'Test'
Owner's avatar
Owner committed
170 171
"

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

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

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

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

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

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

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

Thomas Mueller's avatar
Thomas Mueller committed
223 224 225
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
226
Admin rights are required to execute this command.
227

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

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

242 243 244 245 246
"Commands (DML)","Explicit TABLE","
TABLE [schemaName.]tableName
","
Selects data from a table.

247
This command is an equivalent to SELECT * FROM tableName.
248 249 250 251 252 253 254

FROM, WHERE, GROUP BY, HAVING, and WINDOW clauses from the SELECT command are not allowed.
","
TABLE TEST;
TABLE TEST ORDER BY ID FETCH FIRST ROW ONLY;
"

255
"Commands (DML)","WITH","
256 257
WITH [ RECURSIVE ] { name [( columnName [,...] )] AS ( select ) [,...] }
{ select | insert | update | merge | delete | createTable }
258
","
259
Can be used to create a recursive or non-recursive query (common table expression).
260
For recursive queries the first select has to be a UNION.
261
One or more common table entries can be referred to by name.
262
Column name declarations are now optional - the column names will be inferred from the named select queries.
263
The final action in a WITH statement can be a select, insert, update, merge, delete or create table.
264
","
265
WITH RECURSIVE cte(n) AS (
266 267 268
        SELECT 1
    UNION ALL
        SELECT n + 1
269
        FROM cte
270 271
        WHERE n < 100
)
272 273 274 275
SELECT sum(n) FROM cte;

Example 2:
WITH cte1 AS (
276
        SELECT 1 AS FIRST_COLUMN
277 278
), cte2 AS (
        SELECT FIRST_COLUMN+1 AS FIRST_COLUMN FROM cte1
279
)
280
SELECT sum(FIRST_COLUMN) FROM cte2;
281 282
"

Thomas Mueller's avatar
Thomas Mueller committed
283
"Commands (DDL)","ALTER INDEX RENAME","
284
ALTER INDEX [ IF EXISTS ] indexName RENAME TO newIndexName
Thomas Mueller's avatar
Thomas Mueller committed
285
","
Thomas Mueller's avatar
Thomas Mueller committed
286
Renames an index.
Thomas Mueller's avatar
Thomas Mueller committed
287
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
288 289 290 291
","
ALTER INDEX IDXNAME RENAME TO IDX_TEST_NAME
"

292
"Commands (DDL)","ALTER SCHEMA RENAME","
293
ALTER SCHEMA [ IF EXISTS ] schema RENAME TO newSchemaName
294 295
","
Renames a schema.
Thomas Mueller's avatar
Thomas Mueller committed
296
This command commits an open transaction in this connection.
297 298 299 300
","
ALTER SCHEMA TEST RENAME TO PRODUCTION
"

Thomas Mueller's avatar
Thomas Mueller committed
301
"Commands (DDL)","ALTER SEQUENCE","
302 303 304
ALTER SEQUENCE [ IF EXISTS ] sequenceName
[ RESTART WITH long ]
[ INCREMENT BY long ]
305 306
[ MINVALUE long | NOMINVALUE | NO MINVALUE ]
[ MAXVALUE long | NOMAXVALUE | NO MAXVALUE ]
307 308
[ CYCLE long | NOCYCLE | NO CYCLE ]
[ CACHE long | NOCACHE | NO CACHE ]
Thomas Mueller's avatar
Thomas Mueller committed
309
","
310
Changes the parameters of a sequence.
Thomas Mueller's avatar
Thomas Mueller committed
311
This command does not commit the current transaction; however the new value is used by other
Thomas Mueller's avatar
Thomas Mueller committed
312 313 314 315 316 317
transactions immediately, and rolling back this command has no effect.
","
ALTER SEQUENCE SEQ_ID RESTART WITH 1000
"

"Commands (DDL)","ALTER TABLE ADD","
318
ALTER TABLE [ IF EXISTS ] tableName ADD [ COLUMN ]
319 320
{ [ IF NOT EXISTS ] columnName columnDefinition
    | ( { columnName columnDefinition | constraint } [,...] ) }
321
[ { { BEFORE | AFTER } columnName } | FIRST ]
Thomas Mueller's avatar
Thomas Mueller committed
322
","
Thomas Mueller's avatar
Thomas Mueller committed
323
Adds a new column to a table.
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 329
","
ALTER TABLE TEST ADD CREATEDATE TIMESTAMP
"

"Commands (DDL)","ALTER TABLE ADD CONSTRAINT","
330
ALTER TABLE [ IF EXISTS ] tableName ADD constraint [ CHECK | NOCHECK ]
Thomas Mueller's avatar
Thomas Mueller committed
331 332 333
","
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
334
The required indexes are automatically created if they don't exist yet.
Thomas Mueller's avatar
Thomas Mueller committed
335
It is not possible to disable checking for unique constraints.
Thomas Mueller's avatar
Thomas Mueller committed
336
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
337 338 339 340
","
ALTER TABLE TEST ADD CONSTRAINT NAME_UNIQUE UNIQUE(NAME)
"

341
"Commands (DDL)","ALTER TABLE RENAME CONSTRAINT","
342 343
ALTER TABLE [ IF EXISTS ] tableName RENAME oldConstraintName
TO newConstraintName
344 345 346 347 348 349 350
","
Renames a constraint.
This command commits an open transaction in this connection.
","
ALTER TABLE TEST RENAME CONSTRAINT FOO TO BAR
"

351
"Commands (DDL)","ALTER TABLE ALTER COLUMN","
352
ALTER TABLE [ IF EXISTS ] tableName ALTER COLUMN columnName
353
{ { columnDefinition }
354 355 356 357
    | { RENAME TO name }
    | { RESTART WITH long }
    | { SELECTIVITY int }
    | { SET DEFAULT expression }
358
    | { DROP DEFAULT }
359
    | { SET ON UPDATE expression }
360
    | { DROP ON UPDATE }
361
    | { SET NOT NULL }
362
    | { DROP NOT NULL } | { SET NULL }
363
    | { SET DATA TYPE dataType }
364
    | { SET { VISIBLE | INVISIBLE } } }
Thomas Mueller's avatar
Thomas Mueller committed
365
","
366 367
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
368

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

371 372 373
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
374

375 376 377 378
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
379

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

382 383
DROP DEFAULT removes the default value of a column.

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

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

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

390 391
DROP NOT NULL and SET NULL set a column to allow NULL. The row may not be part of a primary key.

392 393
SET DATA TYPE changes the data type of a column.

394 395 396
SET INVISIBLE makes the column hidden, i.e. it will not appear in SELECT * results.
SET VISIBLE has the reverse effect.

Thomas Mueller's avatar
Thomas Mueller committed
397
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
398
","
399 400 401 402 403 404 405
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;
406 407
ALTER TABLE TEST ALTER COLUMN NAME SET VISIBLE;
ALTER TABLE TEST ALTER COLUMN NAME SET INVISIBLE;
Thomas Mueller's avatar
Thomas Mueller committed
408 409 410
"

"Commands (DDL)","ALTER TABLE DROP COLUMN","
411
ALTER TABLE [ IF EXISTS ] tableName DROP COLUMN [ IF EXISTS ]
412
columnName [,...] | ( columnName [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
413
","
414
Removes column(s) from a table.
Thomas Mueller's avatar
Thomas Mueller committed
415
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
416 417
","
ALTER TABLE TEST DROP COLUMN NAME
418
ALTER TABLE TEST DROP COLUMN NAME1, NAME2
419
ALTER TABLE TEST DROP COLUMN (NAME1, NAME2)
Thomas Mueller's avatar
Thomas Mueller committed
420 421 422
"

"Commands (DDL)","ALTER TABLE DROP CONSTRAINT","
423 424
ALTER TABLE [ IF EXISTS ] tableName DROP
{ CONSTRAINT [ IF EXISTS ] constraintName | PRIMARY KEY }
Thomas Mueller's avatar
Thomas Mueller committed
425 426
","
Removes a constraint or a primary key from a table.
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 DROP CONSTRAINT UNIQUE_NAME
"

"Commands (DDL)","ALTER TABLE SET","
433
ALTER TABLE [ IF EXISTS ] tableName SET REFERENTIAL_INTEGRITY
434
{ FALSE | TRUE } [ CHECK | NOCHECK ]
Thomas Mueller's avatar
Thomas Mueller committed
435 436 437 438 439 440
","
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.
441

Thomas Mueller's avatar
Thomas Mueller committed
442
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
443 444 445 446 447
","
ALTER TABLE TEST SET REFERENTIAL_INTEGRITY FALSE
"

"Commands (DDL)","ALTER TABLE RENAME","
448
ALTER TABLE [ IF EXISTS ] tableName RENAME TO newName
Thomas Mueller's avatar
Thomas Mueller committed
449
","
Thomas Mueller's avatar
Thomas Mueller committed
450
Renames a table.
Thomas Mueller's avatar
Thomas Mueller committed
451
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
452 453 454 455 456
","
ALTER TABLE TEST RENAME TO MY_DATA
"

"Commands (DDL)","ALTER USER ADMIN","
457
ALTER USER userName ADMIN { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
458
","
Thomas Mueller's avatar
Thomas Mueller committed
459 460 461 462
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
463
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
464 465 466 467 468 469 470
","
ALTER USER TOM ADMIN TRUE
"

"Commands (DDL)","ALTER USER RENAME","
ALTER USER userName RENAME TO newUserName
","
Thomas Mueller's avatar
Thomas Mueller committed
471 472 473 474
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
475
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
476
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
477 478 479 480 481
","
ALTER USER TOM RENAME TO THOMAS
"

"Commands (DDL)","ALTER USER SET PASSWORD","
482
ALTER USER userName SET { PASSWORD string | SALT bytes HASH bytes }
Thomas Mueller's avatar
Thomas Mueller committed
483
","
Thomas Mueller's avatar
Thomas Mueller committed
484 485 486 487 488 489
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
490
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
491 492 493 494
","
ALTER USER SA SET PASSWORD 'rioyxlgt'
"

495
"Commands (DDL)","ALTER VIEW RECOMPILE","
496
ALTER VIEW [ IF EXISTS ] viewName RECOMPILE
Thomas Mueller's avatar
Thomas Mueller committed
497 498
","
Recompiles a view after the underlying tables have been changed or created.
Thomas Mueller's avatar
Thomas Mueller committed
499
This command is used for views created using CREATE FORCE VIEW.
Thomas Mueller's avatar
Thomas Mueller committed
500
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
501 502 503 504
","
ALTER VIEW ADDRESS_VIEW RECOMPILE
"

505 506 507 508 509 510 511 512 513
"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
514
"Commands (DDL)","ANALYZE","
515
ANALYZE [ TABLE tableName ] [ SAMPLE_SIZE rowCountInt ]
Thomas Mueller's avatar
Thomas Mueller committed
516
","
517 518 519
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
520 521 522 523 524
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.
525

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
","
ANALYZE SAMPLE_SIZE 1000
"

"Commands (DDL)","COMMENT","
532 533 534 535 536
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
537
","
Thomas Mueller's avatar
Thomas Mueller committed
538 539 540
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
541
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
542 543 544 545 546
","
COMMENT ON TABLE TEST IS 'Table used for testing'
"

"Commands (DDL)","CREATE AGGREGATE","
547
CREATE AGGREGATE [ IF NOT EXISTS ] newAggregateName FOR className
Thomas Mueller's avatar
Thomas Mueller committed
548 549 550
","
Creates a new user-defined aggregate function. The method name must be the full
qualified class name. The class must implement the interface
551
""org.h2.api.Aggregate"" or ""org.h2.api.AggregateFunction"".
Thomas Mueller's avatar
Thomas Mueller committed
552 553

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
554
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
555
","
556
CREATE AGGREGATE SIMPLE_MEDIAN FOR ""com.acme.db.Median""
Thomas Mueller's avatar
Thomas Mueller committed
557 558 559
"

"Commands (DDL)","CREATE ALIAS","
Thomas Mueller's avatar
Thomas Mueller committed
560
CREATE ALIAS [ IF NOT EXISTS ] newFunctionAliasName [ DETERMINISTIC ]
Thomas Mueller's avatar
Thomas Mueller committed
561
[ NOBUFFER ] { FOR classAndMethodName | AS sourceCodeString }
Thomas Mueller's avatar
Thomas Mueller committed
562
","
563 564 565 566 567 568
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.
569 570 571

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

577 578
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.
579 580
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
581 582
as dollar quoted text to avoid escaping problems. If import statements are used,
then the tag @CODE must be added before the method.
583

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

587
If the first parameter of the Java function is a ""java.sql.Connection"", then a
Thomas Mueller's avatar
Thomas Mueller committed
588 589 590
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.
591

Thomas Mueller's avatar
Thomas Mueller committed
592
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
593
This command commits an open transaction in this connection.
594 595

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
596 597 598 599 600
","
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');
601 602
CREATE ALIAS REVERSE AS $$ String reverse(String s) { return new StringBuilder(s).reverse().toString(); } $$;
CALL REVERSE('Test');
603 604 605 606 607
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
608 609 610
"

"Commands (DDL)","CREATE CONSTANT","
611
CREATE CONSTANT [ IF NOT EXISTS ] newConstantName VALUE expression
Thomas Mueller's avatar
Thomas Mueller committed
612
","
Thomas Mueller's avatar
Thomas Mueller committed
613
Creates a new constant.
Thomas Mueller's avatar
Thomas Mueller committed
614
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
615 616 617 618 619
","
CREATE CONSTANT ONE VALUE 1
"

"Commands (DDL)","CREATE DOMAIN","
620 621 622
CREATE DOMAIN [ IF NOT EXISTS ] newDomainName AS dataType
[ DEFAULT expression ] [ [ NOT ] NULL ] [ SELECTIVITY selectivity ]
[ CHECK condition ]
Thomas Mueller's avatar
Thomas Mueller committed
623 624
","
Creates a new data type (domain). The check condition must evaluate to true or
Thomas Mueller's avatar
Thomas Mueller committed
625
to NULL (to prevent NULL, use ""NOT NULL""). In the condition, the term VALUE refers
Thomas Mueller's avatar
Thomas Mueller committed
626
to the value being tested.
627

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

Thomas Mueller's avatar
Thomas Mueller committed
630
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
631 632 633 634 635
","
CREATE DOMAIN EMAIL AS VARCHAR(255) CHECK (POSITION('@', VALUE) > 1)
"

"Commands (DDL)","CREATE INDEX","
636
CREATE
Thomas Mueller's avatar
Thomas Mueller committed
637
{ [ UNIQUE ] [ HASH | SPATIAL] INDEX [ [ IF NOT EXISTS ] newIndexName ]
638 639
    | PRIMARY KEY [ HASH ] }
ON tableName ( indexColumn [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
640
","
Thomas Mueller's avatar
Thomas Mueller committed
641
Creates a new index.
Thomas Mueller's avatar
Thomas Mueller committed
642
This command commits an open transaction in this connection.
643

Thomas Mueller's avatar
Thomas Mueller committed
644
Hash indexes are meant for in-memory databases and memory tables (CREATE MEMORY TABLE).
645 646
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
647
Non-unique keys are supported.
648
Spatial indexes are supported only on Geometry columns.
Thomas Mueller's avatar
Thomas Mueller committed
649 650 651 652 653
","
CREATE INDEX IDXNAME ON TEST(NAME)
"

"Commands (DDL)","CREATE LINKED TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
654
CREATE [ FORCE ] [ [ GLOBAL | LOCAL ] TEMPORARY ]
Thomas Mueller's avatar
Thomas Mueller committed
655
LINKED TABLE [ IF NOT EXISTS ]
656 657
name ( driverString, urlString, userString, passwordString,
[ originalSchemaString, ] originalTableString ) [ EMIT UPDATES | READONLY ]
Thomas Mueller's avatar
Thomas Mueller committed
658 659 660 661 662
","
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.

663 664 665
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
666 667
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
668
work. Linked tables to the same database share one connection.
669

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

Thomas Mueller's avatar
Thomas Mueller committed
672 673 674
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).

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

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

Thomas Mueller's avatar
Thomas Mueller committed
682
Admin rights are required to execute this command.
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
CREATE LINKED TABLE LINK('org.h2.Driver', 'jdbc:h2:test2',
    'sa', 'sa', 'TEST');
Thomas Mueller's avatar
Thomas Mueller committed
687 688 689
CREATE LINKED TABLE LINK('', 'jdbc:h2:test2', 'sa', 'sa',
    '(SELECT * FROM TEST WHERE ID>0)');
CREATE LINKED TABLE LINK('javax.naming.InitialContext',
690 691
    'java:comp/env/jdbc/Test', NULL, NULL,
    '(SELECT * FROM TEST WHERE ID>0)');
Thomas Mueller's avatar
Thomas Mueller committed
692 693 694
"

"Commands (DDL)","CREATE ROLE","
695
CREATE ROLE [ IF NOT EXISTS ] newRoleName
Thomas Mueller's avatar
Thomas Mueller committed
696
","
Thomas Mueller's avatar
Thomas Mueller committed
697
Creates a new role.
Thomas Mueller's avatar
Thomas Mueller committed
698
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
699 700 701 702 703
","
CREATE ROLE READONLY
"

"Commands (DDL)","CREATE SCHEMA","
704 705
CREATE SCHEMA [ IF NOT EXISTS ] name
[ AUTHORIZATION ownerUserName ]
706
[ WITH tableEngineParamName [,...] ]
Thomas Mueller's avatar
Thomas Mueller committed
707 708 709
","
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
710
Specifying the owner currently has no effect.
711 712
Optional table engine parameters are used when CREATE TABLE command
is run on this schema without having its engine params set.
713

Thomas Mueller's avatar
Thomas Mueller committed
714
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
715 716 717 718 719
","
CREATE SCHEMA TEST_SCHEMA AUTHORIZATION SA
"

"Commands (DDL)","CREATE SEQUENCE","
720
CREATE SEQUENCE [ IF NOT EXISTS ] newSequenceName
721
sequenceOptions
Thomas Mueller's avatar
Thomas Mueller committed
722
","
Thomas Mueller's avatar
Thomas Mueller committed
723 724 725
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
726 727 728 729 730

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
731

Thomas Mueller's avatar
Thomas Mueller committed
732
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
733 734 735 736 737
","
CREATE SEQUENCE SEQ_ID
"

"Commands (DDL)","CREATE TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
738 739
CREATE [ CACHED | MEMORY ] [ TEMP | [ GLOBAL | LOCAL ] TEMPORARY ]
TABLE [ IF NOT EXISTS ] name
740
[ ( { columnName columnDefinition | constraint } [,...] ) ]
741 742
[ ENGINE tableEngineName ]
[ WITH tableEngineParamName [,...] ]
743
[ NOT PERSISTENT ] [ TRANSACTIONAL ]
744
[ AS select [ WITH [ NO ] DATA ] ]","
Thomas Mueller's avatar
Thomas Mueller committed
745 746
Creates a new table.

Thomas Mueller's avatar
Thomas Mueller committed
747 748 749 750
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
751
that means memory tables should not get too large.
752

Thomas Mueller's avatar
Thomas Mueller committed
753 754 755 756 757
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,
758
unless the temporary table is created using CREATE CACHED TABLE.
Thomas Mueller's avatar
Thomas Mueller committed
759

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

764 765 766
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.

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

770 771
The column definition is optional if a query is specified.
In that case the column list of the query is used.
772
If the query is specified its results are inserted into created table unless WITH NO DATA is specified.
773

Thomas Mueller's avatar
Thomas Mueller committed
774 775
This command commits an open transaction, except when using
TRANSACTIONAL (only supported for temporary tables).
Thomas Mueller's avatar
Thomas Mueller committed
776 777 778 779 780
","
CREATE TABLE TEST(ID INT PRIMARY KEY, NAME VARCHAR(255))
"

"Commands (DDL)","CREATE TRIGGER","
781 782 783 784 785 786
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
787
","
Thomas Mueller's avatar
Thomas Mueller committed
788 789 790 791 792
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).
793

794 795
The sourceCodeString must define a single method with no parameters that returns ""org.h2.api.Trigger"".
See CREATE ALIAS for requirements regarding the compilation.
796 797 798
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"".
799

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

Thomas Mueller's avatar
Thomas Mueller committed
805
ROLLBACK can be specified in combination with INSERT, UPDATE, and DELETE.
806
Only row based AFTER trigger can be called on ROLLBACK.
807
Exceptions that occur within such triggers are ignored.
808 809
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.
810

811
INSTEAD OF triggers are implicitly row based and behave like BEFORE triggers.
812
Only the first such trigger is called. Such triggers on views are supported.
813
They can be used to make views updatable.
814

Thomas Mueller's avatar
Thomas Mueller committed
815 816
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.
817 818
The trigger is called with both 'old' and 'new' set to null.

819 820 821 822
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
823 824
Committing or rolling back a transaction within a trigger is not allowed, except for SELECT triggers.

Thomas Mueller's avatar
Thomas Mueller committed
825 826 827
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.

828 829
QUEUE is implemented for syntax compatibility with HSQL and has no effect.

Thomas Mueller's avatar
Thomas Mueller committed
830 831
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.
832

Thomas Mueller's avatar
Thomas Mueller committed
833
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
834
","
835
CREATE TRIGGER TRIG_INS BEFORE INSERT ON TEST FOR EACH ROW CALL ""MyTrigger"";
Thomas Mueller's avatar
Thomas Mueller committed
836
CREATE TRIGGER TRIG_SRC BEFORE INSERT ON TEST AS $$org.h2.api.Trigger create() { return new MyTrigger(""constructorParam""); } $$;
837 838
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
839 840
"
"Commands (DDL)","CREATE USER","
841 842
CREATE USER [ IF NOT EXISTS ] newUserName
{ PASSWORD string | SALT bytes HASH bytes } [ ADMIN ]
Thomas Mueller's avatar
Thomas Mueller committed
843
","
Thomas Mueller's avatar
Thomas Mueller committed
844 845 846
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.
847

Thomas Mueller's avatar
Thomas Mueller committed
848
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
849
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
850 851 852 853 854
","
CREATE USER GUEST PASSWORD 'abc'
"

"Commands (DDL)","CREATE VIEW","
Thomas Mueller's avatar
Thomas Mueller committed
855
CREATE [ OR REPLACE ] [ FORCE ] VIEW [ IF NOT EXISTS ] newViewName
856
[ ( columnName [,...] ) ] AS select
Thomas Mueller's avatar
Thomas Mueller committed
857 858
","
Creates a new view. If the force option is used, then the view is created even
Thomas Mueller's avatar
Thomas Mueller committed
859
if the underlying table(s) don't exist.
860

Thomas Mueller's avatar
Thomas Mueller committed
861 862 863 864 865
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.

866 867
Views are not updatable except when using 'instead of' triggers.

Thomas Mueller's avatar
Thomas Mueller committed
868
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
869
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
870 871 872 873 874
","
CREATE VIEW TEST_VIEW AS SELECT * FROM TEST WHERE ID < 100
"

"Commands (DDL)","DROP AGGREGATE","
875
DROP AGGREGATE [ IF EXISTS ] aggregateName
Thomas Mueller's avatar
Thomas Mueller committed
876
","
Thomas Mueller's avatar
Thomas Mueller committed
877 878 879
Drops an existing user-defined aggregate function.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
880
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
881
","
882
DROP AGGREGATE SIMPLE_MEDIAN
Thomas Mueller's avatar
Thomas Mueller committed
883 884 885
"

"Commands (DDL)","DROP ALIAS","
886
DROP ALIAS [ IF EXISTS ] existingFunctionAliasName
Thomas Mueller's avatar
Thomas Mueller committed
887
","
Thomas Mueller's avatar
Thomas Mueller committed
888 889 890
Drops an existing function alias.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
891
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
892
","
Thomas Mueller's avatar
Thomas Mueller committed
893
DROP ALIAS MY_SQRT
Thomas Mueller's avatar
Thomas Mueller committed
894 895 896
"

"Commands (DDL)","DROP ALL OBJECTS","
897
DROP ALL OBJECTS [ DELETE FILES ]
Thomas Mueller's avatar
Thomas Mueller committed
898 899 900 901 902
","
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
903 904 905
back.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
906 907 908 909 910
","
DROP ALL OBJECTS
"

"Commands (DDL)","DROP CONSTANT","
911
DROP CONSTANT [ IF EXISTS ] constantName
Thomas Mueller's avatar
Thomas Mueller committed
912
","
Thomas Mueller's avatar
Thomas Mueller committed
913
Drops a constant.
Thomas Mueller's avatar
Thomas Mueller committed
914
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
915 916 917 918 919
","
DROP CONSTANT ONE
"

"Commands (DDL)","DROP DOMAIN","
920
DROP DOMAIN [ IF EXISTS ] domainName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
921
","
Thomas Mueller's avatar
Thomas Mueller committed
922
Drops a data type (domain).
923 924
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
925
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
926 927 928 929 930
","
DROP DOMAIN EMAIL
"

"Commands (DDL)","DROP INDEX","
931
DROP INDEX [ IF EXISTS ] indexName
Thomas Mueller's avatar
Thomas Mueller committed
932
","
Thomas Mueller's avatar
Thomas Mueller committed
933
Drops an index.
Thomas Mueller's avatar
Thomas Mueller committed
934
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
935 936 937 938 939
","
DROP INDEX IF EXISTS IDXNAME
"

"Commands (DDL)","DROP ROLE","
940
DROP ROLE [ IF EXISTS ] roleName
Thomas Mueller's avatar
Thomas Mueller committed
941
","
Thomas Mueller's avatar
Thomas Mueller committed
942
Drops a role.
Thomas Mueller's avatar
Thomas Mueller committed
943
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
944 945 946 947 948
","
DROP ROLE READONLY
"

"Commands (DDL)","DROP SCHEMA","
949
DROP SCHEMA [ IF EXISTS ] schemaName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
950
","
Thomas Mueller's avatar
Thomas Mueller committed
951
Drops a schema.
952 953
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
954
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
955 956 957 958 959
","
DROP SCHEMA TEST_SCHEMA
"

"Commands (DDL)","DROP SEQUENCE","
960
DROP SEQUENCE [ IF EXISTS ] sequenceName
Thomas Mueller's avatar
Thomas Mueller committed
961
","
Thomas Mueller's avatar
Thomas Mueller committed
962
Drops a sequence.
Thomas Mueller's avatar
Thomas Mueller committed
963
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
964 965 966 967 968
","
DROP SEQUENCE SEQ_ID
"

"Commands (DDL)","DROP TABLE","
Thomas Mueller's avatar
Thomas Mueller committed
969
DROP TABLE [ IF EXISTS ] tableName [,...] [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
970
","
Thomas Mueller's avatar
Thomas Mueller committed
971
Drops an existing table, or a list of tables.
972 973
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
974
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
975 976 977 978 979
","
DROP TABLE TEST
"

"Commands (DDL)","DROP TRIGGER","
980
DROP TRIGGER [ IF EXISTS ] triggerName
Thomas Mueller's avatar
Thomas Mueller committed
981
","
Thomas Mueller's avatar
Thomas Mueller committed
982
Drops an existing trigger.
Thomas Mueller's avatar
Thomas Mueller committed
983
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
984 985 986 987 988
","
DROP TRIGGER TRIG_INS
"

"Commands (DDL)","DROP USER","
989
DROP USER [ IF EXISTS ] userName
Thomas Mueller's avatar
Thomas Mueller committed
990
","
Thomas Mueller's avatar
Thomas Mueller committed
991 992
Drops a user. The current user cannot be dropped.
For compatibility, only unquoted or uppercase user names are allowed.
993

Thomas Mueller's avatar
Thomas Mueller committed
994
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
995
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
996 997 998 999 1000
","
DROP USER TOM
"

"Commands (DDL)","DROP VIEW","
1001
DROP VIEW [ IF EXISTS ] viewName [ RESTRICT | CASCADE ]
Thomas Mueller's avatar
Thomas Mueller committed
1002
","
Thomas Mueller's avatar
Thomas Mueller committed
1003 1004 1005
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
1006
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1007 1008 1009 1010 1011
","
DROP VIEW TEST_VIEW
"

"Commands (DDL)","TRUNCATE TABLE","
1012
TRUNCATE TABLE tableName [ [ CONTINUE | RESTART ] IDENTITY ]
Thomas Mueller's avatar
Thomas Mueller committed
1013
","
1014 1015 1016 1017 1018
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).
1019
Linked tables can't be truncated.
1020
If RESTART IDENTITY is specified next values for auto-incremented columns are restarted.
Thomas Mueller's avatar
Thomas Mueller committed
1021

Thomas Mueller's avatar
Thomas Mueller committed
1022
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1023 1024 1025 1026 1027 1028 1029
","
TRUNCATE TABLE TEST
"

"Commands (Other)","CHECKPOINT","
CHECKPOINT
","
Thomas Mueller's avatar
Thomas Mueller committed
1030
Flushes the data to disk.
Thomas Mueller's avatar
Thomas Mueller committed
1031 1032

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1033 1034 1035 1036 1037 1038 1039
","
CHECKPOINT
"

"Commands (Other)","CHECKPOINT SYNC","
CHECKPOINT SYNC
","
1040
Flushes the data to disk and forces all system buffers be written
Thomas Mueller's avatar
Thomas Mueller committed
1041 1042 1043
to the underlying device.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1044 1045 1046 1047 1048
","
CHECKPOINT SYNC
"

"Commands (Other)","COMMIT","
1049
COMMIT [ WORK ]
Thomas Mueller's avatar
Thomas Mueller committed
1050 1051 1052 1053 1054 1055 1056 1057 1058
","
Commits a transaction.
","
COMMIT
"

"Commands (Other)","COMMIT TRANSACTION","
COMMIT TRANSACTION transactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1059 1060 1061 1062
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
1063 1064 1065 1066 1067
","
COMMIT TRANSACTION XID_TEST
"

"Commands (Other)","GRANT RIGHT","
1068
GRANT { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
1069 1070
{ { SCHEMA schemaName } | { tableName [,...] } }
TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1071
","
Thomas Mueller's avatar
Thomas Mueller committed
1072 1073 1074
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
1075
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1076 1077 1078 1079
","
GRANT SELECT ON TEST TO READONLY
"

1080 1081 1082 1083 1084 1085
"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
1086
This command commits an open transaction in this connection.
1087 1088 1089 1090
","
GRANT ALTER ANY SCHEMA TO Bob
"

Thomas Mueller's avatar
Thomas Mueller committed
1091
"Commands (Other)","GRANT ROLE","
1092
GRANT roleName TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1093
","
Thomas Mueller's avatar
Thomas Mueller committed
1094 1095 1096
Grants a role to a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1097
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1098 1099 1100 1101 1102
","
GRANT READONLY TO PUBLIC
"

"Commands (Other)","HELP","
1103
HELP [ anything [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
1104 1105 1106 1107 1108 1109 1110 1111 1112
","
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
1113 1114
Prepares committing a transaction.
This command is part of the 2-phase-commit protocol.
Thomas Mueller's avatar
Thomas Mueller committed
1115 1116 1117 1118 1119
","
PREPARE COMMIT XID_TEST
"

"Commands (Other)","REVOKE RIGHT","
1120
REVOKE { SELECT | INSERT | UPDATE | DELETE | ALL } [,...] ON
1121 1122
{ { SCHEMA schemaName } | { tableName [,...] } }
FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1123
","
Thomas Mueller's avatar
Thomas Mueller committed
1124 1125 1126
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
1127
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1128 1129 1130 1131 1132
","
REVOKE SELECT ON TEST FROM READONLY
"

"Commands (Other)","REVOKE ROLE","
1133
REVOKE roleName FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1134
","
Thomas Mueller's avatar
Thomas Mueller committed
1135 1136 1137
Removes a role from a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1138
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1139 1140 1141 1142 1143
","
REVOKE READONLY FROM TOM
"

"Commands (Other)","ROLLBACK","
1144
ROLLBACK [ TO SAVEPOINT savepointName ]
Thomas Mueller's avatar
Thomas Mueller committed
1145 1146 1147 1148 1149 1150 1151 1152 1153 1154
","
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
1155 1156 1157 1158
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
1159 1160 1161 1162 1163 1164 1165
","
ROLLBACK TRANSACTION XID_TEST
"

"Commands (Other)","SAVEPOINT","
SAVEPOINT savepointName
","
Thomas Mueller's avatar
Thomas Mueller committed
1166 1167
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
1168 1169 1170 1171 1172
","
SAVEPOINT HALF_DONE
"

"Commands (Other)","SET @","
1173
SET @variableName [ = ] expression
Thomas Mueller's avatar
Thomas Mueller committed
1174
","
Thomas Mueller's avatar
Thomas Mueller committed
1175
Updates a user-defined variable.
Thomas Mueller's avatar
Thomas Mueller committed
1176
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
1177
This command does not commit a transaction, and rollback does not affect it.
Thomas Mueller's avatar
Thomas Mueller committed
1178 1179 1180 1181 1182
","
SET @TOTAL=0
"

"Commands (Other)","SET ALLOW_LITERALS","
1183
SET ALLOW_LITERALS { NONE | ALL | NUMBERS }
Thomas Mueller's avatar
Thomas Mueller committed
1184 1185 1186 1187 1188 1189 1190 1191 1192 1193
","
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
1194 1195
See also CREATE CONSTANT.

Thomas Mueller's avatar
Thomas Mueller committed
1196
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1197
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1198
This setting is persistent.
1199
This setting can be appended to the database URL: ""jdbc:h2:test;ALLOW_LITERALS=NONE""
Thomas Mueller's avatar
Thomas Mueller committed
1200 1201 1202 1203 1204
","
SET ALLOW_LITERALS NONE
"

"Commands (Other)","SET AUTOCOMMIT","
1205
SET AUTOCOMMIT { TRUE | ON | FALSE | OFF }
Thomas Mueller's avatar
Thomas Mueller committed
1206 1207
","
Switches auto commit on or off.
1208
This setting can be appended to the database URL: ""jdbc:h2:test;AUTOCOMMIT=OFF"" -
1209
however this will not work as expected when using a connection pool
1210 1211
(the connection pool manager will re-enable autocommit when returning
the connection to the pool, so autocommit will only be disabled the first
1212
time the connection is used.
Thomas Mueller's avatar
Thomas Mueller committed
1213 1214 1215 1216 1217 1218 1219
","
SET AUTOCOMMIT OFF
"

"Commands (Other)","SET CACHE_SIZE","
SET CACHE_SIZE int
","
1220
Sets the size of the cache in KB (each KB being 1024 bytes) for the current database.
1221 1222
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
1223 1224
Depending on the virtual machine, the actual memory required may be higher.

Thomas Mueller's avatar
Thomas Mueller committed
1225
This setting is persistent and affects all connections as there is only one cache per database.
Thomas Mueller's avatar
Thomas Mueller committed
1226
Using a very small value (specially 0) will reduce performance a lot.
Thomas Mueller's avatar
Thomas Mueller committed
1227 1228
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
1229
It has no effect for in-memory databases.
1230

Thomas Mueller's avatar
Thomas Mueller committed
1231
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1232
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1233
This setting is persistent.
1234
This setting can be appended to the database URL: ""jdbc:h2:test;CACHE_SIZE=8192""
Thomas Mueller's avatar
Thomas Mueller committed
1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246
","
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
1247 1248
server is not responding).

Thomas Mueller's avatar
Thomas Mueller committed
1249
This command is effective immediately, but does not commit an open transaction.
Thomas Mueller's avatar
Thomas Mueller committed
1250 1251 1252 1253
","
SET CLUSTER ''
"

1254
"Commands (Other)","SET BINARY_COLLATION","
1255
SET BINARY_COLLATION { UNSIGNED | SIGNED }
1256
","
Thomas Mueller's avatar
Thomas Mueller committed
1257 1258
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.
1259 1260 1261
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
1262
This command commits an open transaction in this connection.
1263 1264 1265 1266 1267
This setting is persistent.
","
SET BINARY_COLLATION SIGNED
"

1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285
"Commands (Other)","SET UUID_COLLATION","
SET UUID_COLLATION { UNSIGNED | SIGNED }
","
Sets the collation used for comparing UUID columns, the default is SIGNED.
This command can only be executed if there are no tables defined.

SIGNED means signed comparison between first 64 bits of compared values treated as long values
and if they are equal a signed comparison of the last 64 bits of compared values treated as long values.
See also Java ""UUID.compareTo()"".
UNSIGNED means RFC 4122 compatible unsigned comparison.

Admin rights are required to execute this command.
This command commits an open transaction in this connection.
This setting is persistent.
","
SET UUID_COLLATION UNSIGNED
"

1286
"Commands (Other)","SET BUILTIN_ALIAS_OVERRIDE","
1287
SET BUILTIN_ALIAS_OVERRIDE { TRUE | FALSE }
1288 1289 1290 1291 1292 1293 1294 1295 1296 1297
","
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
1298
"Commands (Other)","SET COLLATION","
1299
SET [ DATABASE ] COLLATION
1300 1301
{ OFF | collationName
    [ STRENGTH { PRIMARY | SECONDARY | TERTIARY | IDENTICAL } ] }
Thomas Mueller's avatar
Thomas Mueller committed
1302
","
Thomas Mueller's avatar
Thomas Mueller committed
1303 1304
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
1305 1306
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
1307
TERTIARY is both case- and umlaut-sensitive; IDENTICAL is sensitive to all differences and only affects ordering).
Thomas Mueller's avatar
Thomas Mueller committed
1308

1309 1310 1311 1312 1313
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).
1314 1315
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.
1316

Thomas Mueller's avatar
Thomas Mueller committed
1317
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1318
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1319
This setting is persistent.
1320
This setting can be appended to the database URL: ""jdbc:h2:test;COLLATION='ENGLISH'""
Thomas Mueller's avatar
Thomas Mueller committed
1321 1322
","
SET COLLATION ENGLISH
1323
SET COLLATION CHARSET_CP500
Thomas Mueller's avatar
Thomas Mueller committed
1324 1325 1326
"

"Commands (Other)","SET COMPRESS_LOB","
1327
SET COMPRESS_LOB { NO | LZF | DEFLATE }
Thomas Mueller's avatar
Thomas Mueller committed
1328
","
Thomas Mueller's avatar
Thomas Mueller committed
1329 1330 1331 1332
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
1333 1334
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
1335

Thomas Mueller's avatar
Thomas Mueller committed
1336
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1337
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1338
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1339 1340 1341 1342 1343 1344 1345 1346
","
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
1347 1348 1349 1350
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).
1351
This setting can be appended to the database URL: ""jdbc:h2:test;DATABASE_EVENT_LISTENER='sample.MyListener'""
Thomas Mueller's avatar
Thomas Mueller committed
1352 1353 1354 1355 1356 1357 1358
","
SET DATABASE_EVENT_LISTENER 'sample.MyListener'
"

"Commands (Other)","SET DB_CLOSE_DELAY","
SET DB_CLOSE_DELAY int
","
Thomas Mueller's avatar
Thomas Mueller committed
1359 1360
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
1361 1362 1363 1364
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
1365

Thomas Mueller's avatar
Thomas Mueller committed
1366
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1367
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1368
This setting is persistent.
1369
This setting can be appended to the database URL: ""jdbc:h2:test;DB_CLOSE_DELAY=-1""
Thomas Mueller's avatar
Thomas Mueller committed
1370 1371 1372 1373 1374 1375 1376 1377
","
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
1378 1379
for the new sessions. The default value for this setting is 1000 (one second).

Thomas Mueller's avatar
Thomas Mueller committed
1380
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1381
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1382
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1383 1384 1385 1386 1387
","
SET DEFAULT_LOCK_TIMEOUT 5000
"

"Commands (Other)","SET DEFAULT_TABLE_TYPE","
1388
SET DEFAULT_TABLE_TYPE { MEMORY | CACHED }
Thomas Mueller's avatar
Thomas Mueller committed
1389 1390 1391
","
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
1392
the data is still stored in the database file. The size of memory tables is
Thomas Mueller's avatar
Thomas Mueller committed
1393
limited by the memory. The default is CACHED.
Thomas Mueller's avatar
Thomas Mueller committed
1394

Thomas Mueller's avatar
Thomas Mueller committed
1395
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1396
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1397
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1398
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1399 1400 1401 1402 1403
","
SET DEFAULT_TABLE_TYPE MEMORY
"

"Commands (Other)","SET EXCLUSIVE","
Thomas Mueller's avatar
Thomas Mueller committed
1404
SET EXCLUSIVE { 0 | 1 | 2 }
Thomas Mueller's avatar
Thomas Mueller committed
1405
","
Thomas Mueller's avatar
Thomas Mueller committed
1406 1407 1408 1409 1410 1411 1412 1413 1414 1415
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
1416 1417

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1418
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1419
","
Thomas Mueller's avatar
Thomas Mueller committed
1420
SET EXCLUSIVE 1
Thomas Mueller's avatar
Thomas Mueller committed
1421 1422 1423
"

"Commands (Other)","SET IGNORECASE","
1424
SET IGNORECASE { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
1425 1426 1427 1428 1429
","
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
1430
String literals and parameters are however still considered case sensitive even if this option is set.
Thomas Mueller's avatar
Thomas Mueller committed
1431

Thomas Mueller's avatar
Thomas Mueller committed
1432
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1433
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1434
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1435
This setting can be appended to the database URL: ""jdbc:h2:test;IGNORECASE=TRUE""
Thomas Mueller's avatar
Thomas Mueller committed
1436 1437 1438 1439
","
SET IGNORECASE TRUE
"

1440 1441 1442 1443 1444 1445 1446 1447 1448 1449 1450 1451
"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
1452
This command commits an open transaction in this connection.
1453 1454 1455 1456 1457 1458
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'
"

1459 1460 1461 1462 1463 1464 1465 1466 1467 1468 1469 1470 1471 1472 1473 1474 1475
"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
"

1476
"Commands (Other)","SET LOG","
1477
SET LOG int
1478 1479 1480 1481
","
Sets the transaction log mode. The values 0, 1, and 2 are supported, the default is 2.
This setting affects all connections.

1482
LOG 0 means the transaction log is disabled completely. It is the fastest mode,
1483 1484 1485 1486
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.

1487 1488
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
1489 1490
against power failure is required, but the data must be protected against killing the process.

1491 1492
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
1493 1494
file system, this will also protect against power failure in the majority if cases.

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

Thomas Mueller's avatar
Thomas Mueller committed
1503 1504 1505 1506
"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
1507
(READ_COMMITTED). This setting affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1508 1509 1510 1511 1512 1513 1514 1515 1516 1517 1518 1519 1520

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
1521
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1522
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1523
This setting is persistent.
1524
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_MODE=3""
Thomas Mueller's avatar
Thomas Mueller committed
1525 1526 1527 1528 1529 1530 1531 1532
","
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
1533 1534 1535
value for this setting is 1000 (one second).

This command does not commit a transaction, and rollback does not affect it.
1536
This setting can be appended to the database URL: ""jdbc:h2:test;LOCK_TIMEOUT=10000""
Thomas Mueller's avatar
Thomas Mueller committed
1537 1538 1539 1540 1541 1542 1543
","
SET LOCK_TIMEOUT 1000
"

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

1546
This is the maximum length of an LOB that is stored with the record itself,
1547 1548
and the default value is 128.

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 1553 1554 1555 1556 1557 1558
","
SET MAX_LENGTH_INPLACE_LOB 128
"

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

Thomas Mueller's avatar
Thomas Mueller committed
1565
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1566
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1567
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1568 1569 1570 1571 1572 1573 1574 1575
","
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
1576
are read, then the rows are buffered to disk.
1577
The default is 40000 per GB of available RAM.
Thomas Mueller's avatar
Thomas Mueller committed
1578

Thomas Mueller's avatar
Thomas Mueller committed
1579
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1580
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1581
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1582
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1583 1584 1585 1586 1587 1588 1589
","
SET MAX_MEMORY_ROWS 1000
"

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

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.
Thomas Mueller's avatar
Thomas Mueller committed
1598
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1599
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1600 1601 1602 1603 1604 1605 1606 1607 1608
","
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
1609 1610 1611
operation. The default max size is 100000. 0 means no limit.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1612
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1613
It has no effect for in-memory databases.
1614
This setting can be appended to the database URL: ""jdbc:h2:test;MAX_OPERATION_MEMORY=10000""
Thomas Mueller's avatar
Thomas Mueller committed
1615 1616 1617 1618 1619
","
SET MAX_OPERATION_MEMORY 0
"

"Commands (Other)","SET MODE","
1620
SET MODE { REGULAR | DB2 | DERBY | HSQLDB | MSSQLSERVER | MYSQL | ORACLE | POSTGRESQL }
Thomas Mueller's avatar
Thomas Mueller committed
1621 1622
","
Changes to another database compatibility mode. For details, see Compatibility
Thomas Mueller's avatar
Thomas Mueller committed
1623 1624 1625
Modes in the feature section.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1626
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1627
This command commits an open transaction in this connection.
1628
This setting can be appended to the database URL: ""jdbc:h2:test;MODE=MYSQL""
Thomas Mueller's avatar
Thomas Mueller committed
1629 1630 1631 1632 1633
","
SET MODE HSQLDB
"

"Commands (Other)","SET MULTI_THREADED","
1634
SET MULTI_THREADED { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1635
","
1636 1637 1638
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
1639 1640 1641 1642

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
1643
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1644
This command commits an open transaction in this connection.
1645
This setting can be appended to the database URL: ""jdbc:h2:test;MULTI_THREADED=1""
Thomas Mueller's avatar
Thomas Mueller committed
1646 1647 1648 1649 1650
","
SET MULTI_THREADED 1
"

"Commands (Other)","SET OPTIMIZE_REUSE_RESULTS","
1651
SET OPTIMIZE_REUSE_RESULTS { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1652 1653 1654
","
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
1655 1656
the tables was changed. This option is enabled by default.

Thomas Mueller's avatar
Thomas Mueller committed
1657
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1658
This command commits an open transaction in this connection.
1659
This setting can be appended to the database URL: ""jdbc:h2:test;OPTIMIZE_REUSE_RESULTS=0""
Thomas Mueller's avatar
Thomas Mueller committed
1660 1661 1662 1663 1664 1665 1666 1667 1668
","
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
1669

Thomas Mueller's avatar
Thomas Mueller committed
1670
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1671 1672 1673 1674
","
SET PASSWORD 'abcstzri!.5'
"

1675 1676 1677 1678 1679 1680 1681
"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
1682
This command commits an open transaction in this connection.
1683 1684 1685 1686 1687
Admin rights are required to execute this command, as it affects all connections.
","
SET QUERY_STATISTICS FALSE
"

1688 1689 1690 1691 1692 1693 1694 1695 1696 1697 1698 1699 1700
"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
1701 1702 1703 1704 1705
"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
1706 1707 1708
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
1709 1710 1711 1712 1713
","
SET QUERY_TIMEOUT 10000
"

"Commands (Other)","SET REFERENTIAL_INTEGRITY","
1714
SET REFERENTIAL_INTEGRITY { TRUE | FALSE }
Thomas Mueller's avatar
Thomas Mueller committed
1715 1716 1717
","
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
1718 1719 1720
for one table.

This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1721
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1722
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1723 1724 1725 1726
","
SET REFERENTIAL_INTEGRITY FALSE
"

1727 1728 1729 1730 1731 1732
"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.
1733 1734 1735
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,
1736 1737 1738 1739
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
1740
This command commits an open transaction in this connection.
1741 1742 1743 1744 1745 1746
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
1747 1748 1749 1750 1751
"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
1752

Thomas Mueller's avatar
Thomas Mueller committed
1753
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1754 1755 1756 1757 1758 1759 1760 1761 1762
","
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
1763 1764 1765
connections is PUBLIC.

This command does not commit a transaction, and rollback does not affect it.
1766
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA=ABC""
Thomas Mueller's avatar
Thomas Mueller committed
1767 1768 1769 1770 1771 1772 1773 1774 1775
","
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
1776 1777 1778
connections is PUBLIC.

This command does not commit a transaction, and rollback does not affect it.
1779
This setting can be appended to the database URL: ""jdbc:h2:test;SCHEMA_SEARCH_PATH=ABC,DEF""
Thomas Mueller's avatar
Thomas Mueller committed
1780 1781 1782 1783 1784 1785 1786 1787 1788
","
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
1789 1790 1791
disabled).

This command does not commit a transaction, and rollback does not affect it.
1792
This setting can be appended to the database URL: ""jdbc:h2:test;THROTTLE=50""
Thomas Mueller's avatar
Thomas Mueller committed
1793 1794 1795 1796 1797
","
SET THROTTLE 200
"

"Commands (Other)","SET TRACE_LEVEL","
1798
SET { TRACE_LEVEL_FILE | TRACE_LEVEL_SYSTEM_OUT } int
Thomas Mueller's avatar
Thomas Mueller committed
1799 1800 1801
","
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.
1802
To use SLF4J, append "";TRACE_LEVEL_FILE=4"" to the database URL when opening the database.
Thomas Mueller's avatar
Thomas Mueller committed
1803

Thomas Mueller's avatar
Thomas Mueller committed
1804
This setting is not persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1805
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1806
This command does not commit a transaction, and rollback does not affect it.
1807
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_LEVEL_SYSTEM_OUT=3""
Thomas Mueller's avatar
Thomas Mueller committed
1808 1809 1810 1811 1812 1813 1814 1815 1816 1817 1818
","
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
1819
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1820
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1821
This command commits an open transaction in this connection.
1822
This setting can be appended to the database URL: ""jdbc:h2:test;TRACE_MAX_FILE_SIZE=3""
Thomas Mueller's avatar
Thomas Mueller committed
1823 1824 1825 1826 1827 1828 1829 1830 1831 1832
","
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
1833

Thomas Mueller's avatar
Thomas Mueller committed
1834
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1835 1836 1837 1838 1839 1840 1841 1842
","
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
1843 1844
This setting is persistent. The default is 500 ms.

Thomas Mueller's avatar
Thomas Mueller committed
1845
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1846
This command commits an open transaction in this connection.
1847
This setting can be appended to the database URL: ""jdbc:h2:test;WRITE_DELAY=0""
Thomas Mueller's avatar
Thomas Mueller committed
1848 1849 1850 1851 1852
","
SET WRITE_DELAY 2000
"

"Commands (Other)","SHUTDOWN","
1853
SHUTDOWN [ IMMEDIATELY | COMPACT | DEFRAG ]
Thomas Mueller's avatar
Thomas Mueller committed
1854
","
1855 1856
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
1857
closed automatically when the last connection to it is closed.
Thomas Mueller's avatar
Thomas Mueller committed
1858

1859 1860
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
1861 1862 1863

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,
1864
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
1865 1866

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

1868
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.
1869

Thomas Mueller's avatar
Thomas Mueller committed
1870
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1871
","
1872
SHUTDOWN COMPACT
Thomas Mueller's avatar
Thomas Mueller committed
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 1977 1978 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
"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).
2007 2008
ISO definition is used when first week of year should have at least four days
and week is started with Monday.
2009 2010 2011 2012 2013 2014 2015 2016 2017 2018 2019 2020 2021 2022 2023 2024 2025 2026 2027 2028 2029 2030 2031 2032 2033 2034 2035 2036 2037 2038 2039
","
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
"

2040 2041
"Other Grammar","Alias","
name
Thomas Mueller's avatar
Thomas Mueller committed
2042
","
2043
An alias is a name that is only valid in the context of the statement.
Thomas Mueller's avatar
Thomas Mueller committed
2044
","
2045
A
Thomas Mueller's avatar
Thomas Mueller committed
2046 2047
"

2048 2049
"Other Grammar","And Condition","
condition [ { AND condition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2050
","
2051
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2052
","
2053
ID=1 AND NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2054 2055
"

2056
"Other Grammar","Array","
2057
ARRAY '[' [ expression, [,...] ] ']'
Thomas Mueller's avatar
Thomas Mueller committed
2058
","
2059
An array of values.
Thomas Mueller's avatar
Thomas Mueller committed
2060
","
2061 2062 2063
ARRAY[1, 2]
ARRAY[1]
ARRAY[]
Thomas Mueller's avatar
Thomas Mueller committed
2064 2065
"

2066 2067
"Other Grammar","Boolean","
TRUE | FALSE
2068
","
2069
A boolean value.
2070
","
2071
TRUE
2072 2073
"

2074 2075
"Other Grammar","Bytes","
X'hex'
Thomas Mueller's avatar
Thomas Mueller committed
2076
","
2077
A binary value. The hex value is not case sensitive.
Thomas Mueller's avatar
Thomas Mueller committed
2078
","
2079
X'01FF'
Thomas Mueller's avatar
Thomas Mueller committed
2080 2081
"

2082 2083 2084
"Other Grammar","Case","
CASE expression { WHEN expression THEN expression } [...]
[ ELSE expression ] END
Thomas Mueller's avatar
Thomas Mueller committed
2085
","
2086 2087
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
2088
","
2089
CASE CNT WHEN 0 THEN 'No' WHEN 1 THEN 'One' ELSE 'Some' END
Thomas Mueller's avatar
Thomas Mueller committed
2090 2091
"

2092 2093 2094
"Other Grammar","Case When","
CASE { WHEN expression THEN expression} [...]
[ ELSE expression ] END
Thomas Mueller's avatar
Thomas Mueller committed
2095
","
2096 2097
Returns the first expression where the condition is true. If no else part is
specified, return NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2098
","
2099 2100 2101 2102
CASE WHEN CNT<10 THEN 'Low' ELSE 'High' END
"

"Other Grammar","Cipher","
2103
AES
2104
","
2105
Only the algorithm AES (""AES-128"") is supported currently.
2106 2107
","
AES
Thomas Mueller's avatar
Thomas Mueller committed
2108 2109
"

2110
"Other Grammar","Column Definition","
2111
dataType [ VISIBLE | INVISIBLE ]
2112 2113 2114
[ { DEFAULT expression
    | AS computedColumnExpression
    | GENERATED {ALWAYS | BY DEFAULT} AS IDENTITY [(sequenceOptions)]} ]
2115
[ ON UPDATE expression ] [ [ NOT ] NULL ]
2116
[ { AUTO_INCREMENT | IDENTITY } [ ( startInt [, incrementInt ] ) ] ]
Thomas Mueller's avatar
Thomas Mueller committed
2117 2118
[ SELECTIVITY selectivity ] [ COMMENT expression ]
[ PRIMARY KEY [ HASH ] | UNIQUE ] [ CHECK condition ]
2119 2120
","
Default expressions are used if no explicit value was used when adding a row.
Thomas Mueller's avatar
Thomas Mueller committed
2121
The computed column expression is evaluated and assigned whenever the row changes.
2122 2123 2124
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.
2125

2126 2127 2128 2129 2130
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
2131

2132 2133 2134
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
2135 2136
The options PRIMARY KEY, UNIQUE, and CHECK are not supported for ALTER statements.

Thomas Mueller's avatar
Thomas Mueller committed
2137 2138
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
2139 2140
Conditions are only checked when a row is added or modified
in the table where the constraint exists.
2141

2142
","
Thomas Mueller's avatar
Thomas Mueller committed
2143 2144 2145
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);
2146 2147
"

2148 2149
"Other Grammar","Comments","
-- anythingUntilEndOfLine | // anythingUntilEndOfLine | /* anythingUntilEndComment */
Thomas Mueller's avatar
Thomas Mueller committed
2150
","
2151 2152 2153
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
2154
","
2155
// This is a comment
Thomas Mueller's avatar
Thomas Mueller committed
2156 2157
"

2158
"Other Grammar","Compare","
2159
<> | <= | >= | = | < | > | != | &&
Thomas Mueller's avatar
Thomas Mueller committed
2160
","
2161
Comparison operator. The operator != is the same as <>.
2162
The operator ""&&"" means overlapping; it can only be used with geometry types.
Thomas Mueller's avatar
Thomas Mueller committed
2163
","
2164
<>
Thomas Mueller's avatar
Thomas Mueller committed
2165 2166 2167
"

"Other Grammar","Condition","
2168
operand [ conditionRightHandSide ] | NOT condition | EXISTS ( select )
Thomas Mueller's avatar
Thomas Mueller committed
2169 2170 2171 2172 2173 2174 2175
","
Boolean value or condition.
","
ID<>2
"

"Other Grammar","Condition Right Hand Side","
2176
compare { { { ALL | ANY | SOME } ( select ) } | operand }
2177
    | IS [ NOT ] NULL
2178
    | IS [ NOT ] [ DISTINCT FROM ] operand
2179 2180
    | BETWEEN operand AND operand
    | IN ( { select | expression [,...] } )
2181
    | [ NOT ] [ LIKE | ILIKE ] operand [ ESCAPE string ]
2182
    | [ NOT ] REGEXP operand
Thomas Mueller's avatar
Thomas Mueller committed
2183
","
Thomas Mueller's avatar
Thomas Mueller committed
2184
The right hand side of a condition.
2185

2186 2187 2188 2189 2190 2191
Quantified comparison predicate ALL returns TRUE if specified comparison operation between
left size of condition and each row from a subquery returns TRUE, including case when there are no rows.
ALL predicate returns FALSE if at least one such comparison returns FALSE.
Otherwise it returns NULL.

Quantified comparison predicates ANY and SOME return TRUE if specified comparison operation between
2192
left size of condition and at least one row from a subquery returns TRUE.
2193 2194 2195 2196 2197
ANY and SOME predicates return FALSE if all such comparisons return FALSE.
Otherwise it returns NULL.
Note that these predicates have priority over ANY and SOME aggregate functions with subquery on the right side.
Use parentheses around aggregate function.

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

Thomas Mueller's avatar
Thomas Mueller committed
2201 2202 2203 2204 2205
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).
2206 2207 2208
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.
2209

2210 2211
ILIKE does a case-insensitive compare.

Thomas Mueller's avatar
Thomas Mueller committed
2212
When comparing with REGEXP, regular expression matching is used.
2213
See Java ""Matcher.find"" for details.
Thomas Mueller's avatar
Thomas Mueller committed
2214
","
2215 2216
VALUE > 10
A IS NOT DISTINCT FROM B
Thomas Mueller's avatar
Thomas Mueller committed
2217 2218 2219
LIKE 'Jo%'
"

2220
"Other Grammar","Constraint","
Thomas Mueller's avatar
Thomas Mueller committed
2221 2222 2223 2224 2225
[ constraintNameDefinition ]
{ CHECK expression
    | UNIQUE ( columnName [,...] )
    | referentialConstraint
    | PRIMARY KEY [ HASH ] ( columnName [,...] ) }
Thomas Mueller's avatar
Thomas Mueller committed
2226
","
Thomas Mueller's avatar
Thomas Mueller committed
2227 2228
Defines a constraint.
The check condition must evaluate to TRUE, FALSE or NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2229
TRUE and NULL mean the operation is to be permitted,
Thomas Mueller's avatar
Thomas Mueller committed
2230 2231
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
2232
","
2233
PRIMARY KEY(ID, NAME)
Thomas Mueller's avatar
Thomas Mueller committed
2234 2235
"

2236 2237
"Other Grammar","Constraint Name Definition","
CONSTRAINT [ IF NOT EXISTS ] newConstraintName
Thomas Mueller's avatar
Thomas Mueller committed
2238
","
2239
Defines a constraint name.
Thomas Mueller's avatar
Thomas Mueller committed
2240
","
2241
CONSTRAINT CONST_ID
Thomas Mueller's avatar
Thomas Mueller committed
2242 2243
"

2244 2245
"Other Grammar","Csv Options","
charsetString [, fieldSepString [, fieldDelimString [, escString [, nullString]]]]]
2246
    | optionString
Thomas Mueller's avatar
Thomas Mueller committed
2247
","
2248
Optional parameters for CSVREAD and CSVWRITE.
2249 2250
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
2251 2252
""STRINGDECODE('charset=UTF-8 escape=\"" fieldDelimiter=\"" fieldSeparator=, ' ||""
""'lineComment=# lineSeparator=\n null= rowSeparator=')"".
2253
The following options are supported:
2254

2255
""caseSensitiveColumnNames"" (true or false; disabled by default),
2256

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

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

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

thomasmueller's avatar
thomasmueller committed
2263
""fieldSeparator"" (a comma by default),
2264

2265
""lineComment"" (disabled by default),
2266

2267
""lineSeparator"" (the line separator used for writing; ignored for reading),
2268

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

2272
""preserveWhitespace"" (true or false; disabled by default),
2273

2274
""writeColumnHeader"" (true or false; enabled by default).
2275

Thomas Mueller's avatar
Thomas Mueller committed
2276
For a newline or other special character, use STRINGDECODE as in the example above.
Thomas Mueller's avatar
Thomas Mueller committed
2277
A space needs to be escaped with a backslash (""'\ '""), and
Thomas Mueller's avatar
Thomas Mueller committed
2278 2279 2280
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
2281
","
2282
CALL CSVWRITE('test2.csv', 'SELECT * FROM TEST', 'charset=UTF-8 fieldSeparator=|');
Thomas Mueller's avatar
Thomas Mueller committed
2283 2284
"

2285 2286 2287
"Other Grammar","Data Type","
intType | booleanType | tinyintType | smallintType | bigintType | identityType
    | decimalType | doubleType | realType | dateType | timeType | timestampType
2288 2289
    | timestampWithTimeZoneType | binaryType | otherType | varcharType
    | varcharIgnorecaseType | charType | blobType | clobType | uuidType
2290
    | arrayType | enumType | intervalType
Thomas Mueller's avatar
Thomas Mueller committed
2291
","
2292
A data type definition.
Thomas Mueller's avatar
Thomas Mueller committed
2293
","
2294
INT
Thomas Mueller's avatar
Thomas Mueller committed
2295 2296
"

2297 2298
"Other Grammar","Date","
DATE 'yyyy-MM-dd'
Thomas Mueller's avatar
Thomas Mueller committed
2299
","
2300
A date literal. The limitations are the same as for the Java data type
2301
""java.sql.Date"", but for compatibility with other databases the suggested minimum
2302
and maximum years are 0001 and 9999.
Thomas Mueller's avatar
Thomas Mueller committed
2303
","
2304
DATE '2004-12-31'
Thomas Mueller's avatar
Thomas Mueller committed
2305 2306
"

2307
"Other Grammar","Decimal","
2308 2309
[ + | - ] { { number [ . number ] } | { . number } }
[ E [ + | - ] expNumber [...] ] ]
2310
","
Thomas Mueller's avatar
Thomas Mueller committed
2311 2312 2313 2314 2315 2316
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)"".
2317
","
Thomas Mueller's avatar
Thomas Mueller committed
2318 2319 2320
SELECT -1600.05
SELECT CAST(0 AS DOUBLE)
SELECT -1.4e-10
2321 2322
"

2323 2324
"Other Grammar","Digit","
0-9
Thomas Mueller's avatar
Thomas Mueller committed
2325
","
2326
A digit.
Thomas Mueller's avatar
Thomas Mueller committed
2327
","
2328
0
Thomas Mueller's avatar
Thomas Mueller committed
2329 2330
"

2331 2332
"Other Grammar","Dollar Quoted String","
$$anythingExceptTwoDollarSigns$$
Thomas Mueller's avatar
Thomas Mueller committed
2333
","
2334 2335 2336
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
2337
","
2338
$$John's car$$
Thomas Mueller's avatar
Thomas Mueller committed
2339 2340
"

2341 2342
"Other Grammar","Expression","
andCondition [ { OR andCondition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2343
","
2344
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2345
","
2346
ID=1 OR NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2347 2348
"

2349
"Other Grammar","Factor","
2350
term [ { { * | / | % } term } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2351
","
2352
A value or a numeric factor.
Thomas Mueller's avatar
Thomas Mueller committed
2353
","
2354
ID * 10
Thomas Mueller's avatar
Thomas Mueller committed
2355 2356
"

2357 2358
"Other Grammar","Hex","
{ { digit | a-f | A-F } { digit | a-f | A-F } } [...]
Thomas Mueller's avatar
Thomas Mueller committed
2359
","
2360 2361
The hexadecimal representation of a number or of bytes. Two characters are one
byte.
Thomas Mueller's avatar
Thomas Mueller committed
2362
","
2363
cafe
Thomas Mueller's avatar
Thomas Mueller committed
2364 2365
"

2366 2367
"Other Grammar","Hex Number","
[ + | - ] 0x hex
Thomas Mueller's avatar
Thomas Mueller committed
2368
","
2369
A number written in hexadecimal notation.
Thomas Mueller's avatar
Thomas Mueller committed
2370
","
2371
0xff
Thomas Mueller's avatar
Thomas Mueller committed
2372 2373
"

2374 2375
"Other Grammar","Index Column","
columnName [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
Thomas Mueller's avatar
Thomas Mueller committed
2376
","
2377 2378 2379
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
2380
","
2381
NAME
Thomas Mueller's avatar
Thomas Mueller committed
2382 2383
"

2384 2385 2386 2387 2388 2389 2390 2391 2392 2393 2394
"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
2395
"Other Grammar","Int","
2396
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2397 2398 2399 2400 2401 2402 2403
","
The maximum integer number is 2147483647, the minimum is -2147483648.
","
10
"

"Other Grammar","Long","
2404
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2405 2406 2407 2408 2409 2410
","
Long numbers are between -9223372036854775808 and 9223372036854775807.
","
100000
"

2411 2412 2413 2414 2415 2416 2417 2418 2419
"Other Grammar","Merge when clause","
mergeWhenMatchedClause|mergeWhenNotMatchedClause
","
WHEN MATCHED or WHEN NOT MATCHED clause for MERGE USING command.
","
WHEN MATCHED THEN DELETE
"

"Other Grammar","Merge when matched clause","
2420 2421 2422
WHEN MATCHED [ AND expression ] THEN
UPDATE SET setClauseList
    | DELETE
2423
    | {UPDATE SET setClauseList [ WHERE expression ] DELETE [ WHERE expression ]}
2424 2425 2426 2427
","
WHEN MATCHED clause for MERGE USING command.

If both UPDATE and DELETE are specified, DELETE can delete only rows that were updated,
2428
WHERE condition in DELETE clause can be used to specify which updated rows should be deleted.
2429 2430 2431 2432 2433 2434 2435
This condition checks values in updated row.
","
WHEN MATCHED THEN UPDATE SET VALUE = S.VALUE
WHEN MATCHED THEN DELETE
"

"Other Grammar","Merge when not matched clause","
2436
WHEN NOT MATCHED [ AND expression ] THEN INSERT insertColumnsAndSource
2437 2438 2439 2440 2441 2442
","
WHEN NOT MATCHED clause for MERGE USING command.
","
WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)
"

2443
"Other Grammar","Name","
2444
{ { A-Z|_ } [ { A-Z|_|0-9 } [...] ] } | quotedName
Thomas Mueller's avatar
Thomas Mueller committed
2445
","
2446
Names are not case sensitive. There is no maximum name length.
Thomas Mueller's avatar
Thomas Mueller committed
2447
","
2448
TEST
Thomas Mueller's avatar
Thomas Mueller committed
2449 2450
"

2451 2452
"Other Grammar","Null","
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2453
","
2454
NULL is a value without data type and means 'unknown value'.
Thomas Mueller's avatar
Thomas Mueller committed
2455
","
2456
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2457 2458
"

2459 2460 2461 2462 2463 2464 2465 2466
"Other Grammar","Number","
digit [...]
","
The maximum length of the number depends on the data type used.
","
100
"

Thomas Mueller's avatar
Thomas Mueller committed
2467
"Other Grammar","Numeric","
Thomas Mueller's avatar
Thomas Mueller committed
2468
decimal | int | long | hexNumber
Thomas Mueller's avatar
Thomas Mueller committed
2469
","
Thomas Mueller's avatar
Thomas Mueller committed
2470
The data type of a numeric value is always the lowest possible for the given value.
Thomas Mueller's avatar
Thomas Mueller committed
2471 2472 2473 2474 2475 2476 2477
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
"

2478 2479
"Other Grammar","Operand","
summand [ { || summand } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2480
","
2481
A value or a concatenation of values.
Thomas Mueller's avatar
Thomas Mueller committed
2482
In the default mode, the result is NULL if either parameter is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
2483
","
2484
'Hi' || ' Eva'
Thomas Mueller's avatar
Thomas Mueller committed
2485 2486
"

2487 2488
"Other Grammar","Order","
{ int | expression } [ ASC | DESC ] [ NULLS { FIRST | LAST } ]
Thomas Mueller's avatar
Thomas Mueller committed
2489
","
2490 2491 2492
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
2493
","
2494
NAME DESC NULLS LAST
Thomas Mueller's avatar
Thomas Mueller committed
2495 2496
"

2497 2498
"Other Grammar","Quoted Name","
""anythingExceptDoubleQuote""
Thomas Mueller's avatar
Thomas Mueller committed
2499
","
2500 2501 2502
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
2503
","
2504
""FirstName""
Thomas Mueller's avatar
Thomas Mueller committed
2505 2506
"

2507 2508 2509
"Other Grammar","Referential Constraint","
FOREIGN KEY ( columnName [,...] )
REFERENCES [ refTableName ] [ ( refColumnName [,...] ) ]
Thomas Mueller's avatar
Thomas Mueller committed
2510
[ ON DELETE referentialAction ] [ ON UPDATE referentialAction ]
Thomas Mueller's avatar
Thomas Mueller committed
2511
","
Thomas Mueller's avatar
Thomas Mueller committed
2512 2513 2514
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
2515 2516 2517
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
2518
","
2519
FOREIGN KEY(ID) REFERENCES TEST(ID)
Thomas Mueller's avatar
Thomas Mueller committed
2520 2521
"

Thomas Mueller's avatar
Thomas Mueller committed
2522 2523 2524 2525 2526 2527 2528 2529 2530 2531 2532
"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
"

2533
"Other Grammar","Script Compression Encryption","
2534 2535
[ COMPRESSION { DEFLATE | LZF | ZIP | GZIP } ]
[ CIPHER cipher PASSWORD string ]
Thomas Mueller's avatar
Thomas Mueller committed
2536
","
2537 2538
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
2539 2540 2541 2542 2543
LZF is faster but uses more space.
","
COMPRESSION LZF
"

2544 2545 2546 2547 2548 2549 2550 2551 2552 2553
"Other Grammar","Row value expression","
ROW (expression, [,...])
    | ( [ expression, expression [,...] ] )
","
A row value expression.
","
ROW (1)
(1, 2)
"

2554
"Other Grammar","Select Expression","
2555
wildcardExpression | expression [ [ AS ] columnAlias ]
Thomas Mueller's avatar
Thomas Mueller committed
2556
","
2557
An expression in a SELECT statement.
Thomas Mueller's avatar
Thomas Mueller committed
2558
","
2559
ID AS VALUE
Thomas Mueller's avatar
Thomas Mueller committed
2560 2561
"

2562 2563 2564 2565 2566 2567 2568 2569 2570 2571 2572 2573 2574
"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
"

2575
"Other Grammar","Set clause list","
2576
{ { columnName = { DEFAULT | expression } } [,...] }
2577
    | { ( columnName [,...] ) = {rowValueExpression|(select)} }
2578 2579 2580 2581
","
List of SET clauses.
","
NAME = 'Test', VALUE = 2
2582 2583
(A, B) = (1, 2)
(A, B) = (SELECT X, Y FROM OTHER T2 WHERE T1.ID = T2.ID)
2584 2585
"

2586 2587
"Other Grammar","String","
'anythingExceptSingleQuote'
Thomas Mueller's avatar
Thomas Mueller committed
2588
","
2589 2590
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
2591
","
2592
'John''s car'
Thomas Mueller's avatar
Thomas Mueller committed
2593 2594
"

2595 2596
"Other Grammar","Summand","
factor [ { { + | - } factor } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2597
","
Thomas Mueller's avatar
Thomas Mueller committed
2598
A value or a numeric sum.
Thomas Mueller's avatar
Thomas Mueller committed
2599

Thomas Mueller's avatar
Thomas Mueller committed
2600
Please note the text concatenation operator is ""||"".
Thomas Mueller's avatar
Thomas Mueller committed
2601
","
2602
ID + 20
Thomas Mueller's avatar
Thomas Mueller committed
2603 2604
"

2605
"Other Grammar","Table Expression","
2606 2607
{ [ schemaName. ] tableName | ( select ) | valuesExpression }
[ [ AS ] newTableAlias [ ( columnName [,...] ) ] ]
2608
[ USE INDEX ([ indexName [,...] ]) ]
2609 2610
[ { { LEFT | RIGHT } [ OUTER ] | [ INNER ] | CROSS | NATURAL }
    JOIN tableExpression [ ON expression ] ]
Thomas Mueller's avatar
Thomas Mueller committed
2611
","
2612 2613 2614
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
2615
","
2616
TEST AS T LEFT JOIN TEST AS T1 ON T.ID = T1.ID
Thomas Mueller's avatar
Thomas Mueller committed
2617 2618
"

2619 2620 2621 2622 2623 2624 2625 2626 2627
"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;
"

2628 2629 2630 2631 2632 2633 2634 2635 2636 2637
"Other Grammar","Wildcard expression","
{* | tableAlias.*} [EXCEPT ([tableAlias.]columnName, [,...])]
","
A wildcard expression in a SELECT statement.
A wildcard expression represents all visible columns. Some columns can be excluded with optional EXCEPT clause.
","
*
* EXCEPT (DATA)
"

2638 2639
"Other Grammar","Window name or specification","
windowName | windowSpecification
2640
","
2641
A window name or inline specification for a window function or aggregate.
2642

2643 2644 2645
Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
2646
W1
2647
(ORDER BY ID)
2648 2649 2650 2651 2652 2653 2654 2655
"

"Other Grammar","Window specification","
([existingWindowName]
[PARTITION BY expression [,...]] [ORDER BY order [,...]]
[windowFrame])
","
A window specification for a window, window function or aggregate.
2656 2657 2658 2659 2660 2661 2662 2663 2664 2665 2666 2667

If name of an existing window is specified its clauses are used by default.

Optional window partition clause separates rows into independent partitions.
Each partition is processed separately.
If this clause is not present there is one implicit partition with all rows.

Optional window order clause specifies order of rows in the partition.
If some rows have the same order position they are considered as a group of rows in optional window frame clause.

Optional window frame clause specifies which rows are processed by a window function,
see its documentation for a more details.
2668 2669 2670
","
()
(W1 ORDER BY ID)
2671 2672
(PARTITION BY CATEGORY)
(PARTITION BY CATEGORY ORDER BY NAME, ID)
2673 2674 2675 2676
(ORDER BY Y RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES)
"

"Other Grammar","Window frame","
2677
ROWS|RANGE|GROUP
2678
{windowFramePreceding|BETWEEN windowFrameBound AND windowFrameBound}
2679 2680 2681
[EXCLUDE {CURRENT ROW|GROUP|TIES|NO OTHERS}]
","
A window frame clause.
2682
May be specified only for aggregates and FIRST_VALUE(), LAST_VALUE(), and NTH_VALUE() window functions.
2683 2684 2685 2686 2687 2688 2689 2690 2691 2692 2693 2694 2695 2696 2697 2698 2699 2700

If this clause is not specified for an aggregate or window function that supports this clause
the default window frame depends on window order clause.
If window order clause is also not specified
the default window frame contains all the rows in the partition.
If window order clause is specified
the default window frame contains all preceding rows and all rows from the current group.

Window frame unit determines how rows or groups of rows are selected and counted.
If ROWS is specified rows are not grouped in any way and relative numbers of rows are used in bounds.
If RANGE is specified rows are grouped according window order clause,
preceding and following values mean the difference between value in the current row and in the target rows,
and CURRENT ROW in bound specification means current group of rows.
If GROUPS is specified rows are grouped according window order clause,
preceding and following values means relative number of groups of rows,
and CURRENT ROW in bound specification means current group of rows.

If only window frame preceding clause is specified it is treated as
2701
BETWEEN windowFramePreceding AND CURRENT ROW.
2702 2703 2704 2705 2706 2707

Optional window frame exclusion clause specifies rows that should be excluded from the frame.
EXCLUDE CURRENT ROW excludes only the current row regardless the window frame unit.
EXCLUDE GROUP excludes the whole current group of rows, including the current row.
EXCLUDE TIES excludes the current group of rows, but not the current row.
EXCLUDE NO OTHERS is default and it does not exclude anything.
2708
","
2709
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES
2710 2711
"

2712 2713 2714 2715
"Other Grammar","Window frame preceding","
UNBOUNDED PRECEDING|value PRECEDING|CURRENT ROW
","
A window frame preceding clause.
2716
If value is specified it should not be negative.
2717 2718 2719 2720 2721 2722
","
UNBOUNDED PRECEDING
1 PRECEDING
CURRENT ROW
"

2723 2724 2725
"Other Grammar","Window frame bound","
UNBOUNDED PRECEDING|value PRECEDING|CURRENT ROW
    |value FOLLOWING|UNBOUNDED FOLLOWING
2726
","
2727
A window frame bound clause.
2728
If value is specified it should not be negative.
2729
","
2730
UNBOUNDED PRECEDING
2731 2732 2733 2734 2735
UNBOUNDED FOLLOWING
1 FOLLOWING
CURRENT ROW
"

2736 2737 2738 2739 2740 2741 2742 2743 2744 2745 2746 2747
"Other Grammar","Term","
value
    | columnName
    | ?[ int ]
    | NEXT VALUE FOR sequenceName
    | function
    | { - | + } term
    | ( expression )
    | select
    | case
    | caseWhen
    | tableAlias.columnName
2748
    | userDefinedFunctionName
Thomas Mueller's avatar
Thomas Mueller committed
2749
","
2750
A value. Parameters can be indexed, for example ""?1"" meaning the first parameter.
Thomas Mueller's avatar
Thomas Mueller committed
2751
Each table has a pseudo-column named ""_ROWID_"" that contains the unique row identifier.
Thomas Mueller's avatar
Thomas Mueller committed
2752
","
2753 2754 2755 2756
'Hello'
"

"Other Grammar","Time","
2757
TIME [ WITHOUT TIME ZONE ] 'hh:mm:ss[.nnnnnnnnn]'
2758
","
2759
A time literal. A value is between 0:00:00 and 23:59:59.999999999
2760
and has nanosecond resolution.
2761 2762 2763 2764 2765
","
TIME '23:59:59'
"

"Other Grammar","Timestamp","
2766
TIMESTAMP [ WITHOUT TIME ZONE ] 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]'
2767 2768
","
A timestamp literal. The limitations are the same as for the Java data type
2769
""java.sql.Timestamp"", but for compatibility with other databases the suggested
2770 2771 2772 2773 2774
minimum and maximum years are 0001 and 9999.
","
TIMESTAMP '2005-12-31 23:59:59'
"

2775
"Other Grammar","Timestamp with time zone","
2776
TIMESTAMP WITH TIME ZONE 'yyyy-MM-dd hh:mm:ss[.nnnnnnnnn]
2777 2778 2779 2780 2781 2782 2783 2784 2785 2786 2787
[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'
"

2788 2789 2790 2791 2792 2793 2794 2795
"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'
"

2796 2797 2798 2799 2800 2801 2802 2803 2804 2805 2806 2807 2808 2809 2810 2811 2812 2813 2814 2815 2816 2817 2818 2819 2820 2821 2822 2823 2824 2825 2826 2827 2828 2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840 2841 2842 2843 2844 2845 2846 2847 2848 2849 2850 2851 2852 2853 2854 2855 2856
"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.
","
2857
INTERVAL '10 11' DAY TO HOUR
2858 2859 2860 2861 2862 2863 2864 2865 2866 2867 2868 2869 2870 2871 2872 2873 2874 2875 2876 2877 2878 2879 2880 2881 2882 2883 2884 2885 2886 2887 2888 2889 2890 2891 2892 2893 2894 2895 2896 2897 2898 2899 2900 2901
"

"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
2902 2903 2904
    | intervalSecond | intervalYearToMonth | intervalDayToHour
    | intervalDayToMinute | intervalDayToSecond | intervalHourToMinute
    | intervalHourToSecond | intervalMinuteToSecond
2905 2906 2907 2908 2909 2910
","
An interval literal.
","
INTERVAL '1-2' YEAR TO MONTH
"

2911
"Other Grammar","Value","
2912
string | dollarQuotedString | numeric | dateAndTime | boolean | bytes
2913
    | interval | array | null
2914
","
Thomas Mueller's avatar
Thomas Mueller committed
2915
A literal value of any data type, or null.
2916 2917
","
10
Thomas Mueller's avatar
Thomas Mueller committed
2918 2919 2920 2921 2922 2923 2924
"

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

2925
Mapped to ""java.lang.Integer"".
Thomas Mueller's avatar
Thomas Mueller committed
2926 2927 2928 2929 2930 2931 2932 2933 2934
","
INT
"

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

2935
Mapped to ""java.lang.Boolean"".
Thomas Mueller's avatar
Thomas Mueller committed
2936 2937 2938 2939 2940 2941 2942 2943 2944
","
BOOLEAN
"

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

2945
Mapped to ""java.lang.Byte"".
Thomas Mueller's avatar
Thomas Mueller committed
2946 2947 2948 2949 2950 2951 2952 2953 2954
","
TINYINT
"

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

2955
Mapped to ""java.lang.Short"".
Thomas Mueller's avatar
Thomas Mueller committed
2956 2957 2958 2959 2960 2961 2962 2963 2964
","
SMALLINT
"

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

2965
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2966 2967 2968 2969 2970 2971 2972 2973 2974 2975 2976
","
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.

2977
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2978 2979 2980 2981 2982
","
IDENTITY
"

"Data Types","DECIMAL Type","
2983
{ DECIMAL | NUMBER | DEC | NUMERIC } ( precisionInt [ , scaleInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
2984 2985 2986 2987
","
Data type with fixed precision and scale. This data type is recommended for
storing currency values.

2988
Mapped to ""java.math.BigDecimal"".
Thomas Mueller's avatar
Thomas Mueller committed
2989 2990 2991 2992 2993
","
DECIMAL(20, 2)
"

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

3000
Mapped to ""java.lang.Double"".
Thomas Mueller's avatar
Thomas Mueller committed
3001 3002 3003 3004 3005
","
DOUBLE
"

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

3012
Mapped to ""java.lang.Float"".
Thomas Mueller's avatar
Thomas Mueller committed
3013 3014 3015 3016 3017
","
REAL
"

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

3023
Mapped to ""java.sql.Time"". When converted to a ""java.sql.Date"", the date is set to ""1970-01-01"".
3024
""java.time.LocalTime"" is also supported on Java 8 and later versions.
3025
Use ""java.time.LocalTime"" or ""String"" instead of ""java.sql.Time"" when non-zero precision is needed.
3026 3027
Cast from higher fractional seconds precision to lower fractional seconds precision performs round half up;
if result of rounding is higher than maximum supported value 23:59:59.999999999 it is saturated to 23:59:59.999999999.
Thomas Mueller's avatar
Thomas Mueller committed
3028 3029
","
TIME
3030
TIME(9)
Thomas Mueller's avatar
Thomas Mueller committed
3031 3032 3033 3034 3035
"

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

3038
Mapped to ""java.sql.Date"", with the time set to ""00:00:00""
Thomas Mueller's avatar
Thomas Mueller committed
3039
(or to the next possible time if midnight doesn't exist for the given date and timezone due to a daylight saving change).
3040
""java.time.LocalDate"" is also supported on Java 8 and later versions.
Thomas Mueller's avatar
Thomas Mueller committed
3041 3042 3043 3044 3045
","
DATE
"

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

3054 3055
Mapped to ""java.sql.Timestamp"" (""java.util.Date"" may be used too).
""java.time.LocalDateTime"" is also supported on Java 8 and later versions.
3056
Cast from higher fractional seconds precision to lower fractional seconds precision performs round half up.
Thomas Mueller's avatar
Thomas Mueller committed
3057 3058
","
TIMESTAMP
3059
TIMESTAMP(9)
Thomas Mueller's avatar
Thomas Mueller committed
3060 3061
"

3062
"Data Types","TIMESTAMP WITH TIME ZONE Type","
3063
TIMESTAMP [ ( precisionInt ) ] WITH TIME ZONE
3064
","
3065
The timestamp with time zone data type.
3066
Stored internally as a BCD-encoded date, nanoseconds since midnight, and time zone offset in minutes.
3067
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3068

3069 3070 3071 3072 3073 3074 3075
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.
3076
Cast from higher fractional seconds precision to lower fractional seconds precision performs round half up.
3077
","
3078
TIMESTAMP WITH TIME ZONE
3079
TIMESTAMP(9) WITH TIME ZONE
3080 3081
"

Thomas Mueller's avatar
Thomas Mueller committed
3082
"Data Types","BINARY Type","
3083 3084
{ BINARY | VARBINARY | BINARY VARYING
    | LONGVARBINARY | RAW | BYTEA }
3085
[ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3086
","
3087 3088 3089 3090 3091
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
3092 3093 3094 3095 3096 3097 3098 3099 3100

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

"Data Types","OTHER Type","
OTHER
","
Thomas Mueller's avatar
Thomas Mueller committed
3101 3102 3103 3104 3105
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
3106

3107
Mapped to ""java.lang.Object"" (or any subclass).
Thomas Mueller's avatar
Thomas Mueller committed
3108 3109 3110 3111 3112
","
OTHER
"

"Data Types","VARCHAR Type","
3113
{ VARCHAR | CHARACTER VARYING | LONGVARCHAR | VARCHAR2 | NVARCHAR
3114
    | NVARCHAR2 | VARCHAR_CASESENSITIVE} [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3115
","
Thomas Mueller's avatar
Thomas Mueller committed
3116
A Unicode String.
Thomas Mueller's avatar
Thomas Mueller committed
3117 3118 3119 3120 3121 3122 3123
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
3124

3125
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3126 3127 3128 3129 3130
","
VARCHAR(255)
"

"Data Types","VARCHAR_IGNORECASE Type","
3131
VARCHAR_IGNORECASE [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3132
","
Thomas Mueller's avatar
Thomas Mueller committed
3133
Same as VARCHAR, but not case sensitive when comparing.
Thomas Mueller's avatar
Thomas Mueller committed
3134 3135 3136 3137 3138 3139 3140
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
3141

3142
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3143 3144 3145 3146 3147
","
VARCHAR_IGNORECASE
"

"Data Types","CHAR Type","
3148
{ CHAR | CHARACTER | NCHAR } [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3149
","
Thomas Mueller's avatar
Thomas Mueller committed
3150 3151 3152
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
3153

Thomas Mueller's avatar
Thomas Mueller committed
3154 3155
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
3156

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

3160
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3161 3162 3163 3164 3165
","
CHAR(10)
"

"Data Types","BLOB Type","
3166 3167
{ BLOB | BINARY LARGE OBJECT
    | TINYBLOB | MEDIUMBLOB | LONGBLOB | IMAGE | OID }
3168
[ ( precisionInt [K|M|G|T|P]) ]
Thomas Mueller's avatar
Thomas Mueller committed
3169 3170 3171
","
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
3172
""PreparedStatement.setBinaryStream"" to store values. See also CLOB and
Thomas Mueller's avatar
Thomas Mueller committed
3173 3174
Advanced / Large Objects.

3175
Mapped to ""java.sql.Blob"" (""java.io.InputStream"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3176 3177
","
BLOB
3178
BLOB(10K)
Thomas Mueller's avatar
Thomas Mueller committed
3179 3180 3181
"

"Data Types","CLOB Type","
3182 3183
{ CLOB | CHARACTER LARGE OBJECT
    | TINYTEXT | TEXT | MEDIUMTEXT | LONGTEXT | NTEXT | NCLOB }
3184
[ ( precisionInt [K|M|G|T|P] [CHARACTERS|OCTETS]) ]
Thomas Mueller's avatar
Thomas Mueller committed
3185 3186 3187 3188 3189
","
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
3190
""PreparedStatement.setCharacterStream"" to store values. See also Advanced / Large Objects.
Thomas Mueller's avatar
Thomas Mueller committed
3191 3192 3193 3194 3195

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.

3196 3197
Precision, if any, should be specified in characters, CHARACTERS and OCTETS units have no effect in H2.

3198
Mapped to ""java.sql.Clob"" (""java.io.Reader"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3199 3200
","
CLOB
3201
CLOB(10K)
Thomas Mueller's avatar
Thomas Mueller committed
3202 3203 3204 3205 3206
"

"Data Types","UUID Type","
UUID
","
Thomas Mueller's avatar
Thomas Mueller committed
3207 3208 3209 3210
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
3211

Thomas Mueller's avatar
Thomas Mueller committed
3212 3213 3214 3215 3216
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
3217
For details, see the documentation of ""java.util.UUID"".
Thomas Mueller's avatar
Thomas Mueller committed
3218 3219 3220 3221 3222 3223 3224
","
UUID
"

"Data Types","ARRAY Type","
ARRAY
","
Thomas Mueller's avatar
Thomas Mueller committed
3225
An array of values.
3226
Mapped to ""java.lang.Object[]"" (arrays of any non-primitive type are also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3227 3228 3229

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
3230 3231 3232 3233
","
ARRAY
"

3234 3235 3236 3237 3238 3239 3240 3241 3242 3243 3244 3245 3246 3247
"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')
"
3248 3249
"Data Types","GEOMETRY Type","
GEOMETRY
3250 3251 3252 3253 3254 3255 3256 3257 3258
    [({ GEOMETRY |
    { POINT
    | LINESTRING
    | POLYGON
    | MULTIPOINT
    | MULTILINESTRING
    | MULTIPOLYGON
    | GEOMETRYCOLLECTION } [Z|M|ZM]}
    [, sridInt] )]
3259
","
3260
A spatial geometry type.
3261 3262 3263 3264 3265
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.
3266
GEOMETRY constraint means no restrictions on type or dimension system of geometry.
3267 3268 3269
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.
3270 3271
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.
3272 3273
Only a subset of EWKB and EWKT features is supported.
Supported objects are POINT, LINESTRING, POLYGON, MULTIPOINT, MULTILINESTRING, MULTIPOLYGON, and GEOMETRYCOLLECTION.
3274
Supported dimension systems are 2D (XY), Z (XYZ), M (XYM), and ZM (XYZM).
3275
SRID (spatial reference system identifier) is supported.
3276

3277
Use a quoted string containing a WKT/EWKT formatted string or ""PreparedStatement.setObject()"" to store values,
3278 3279
and ""ResultSet.getObject(..)"" or ""ResultSet.getString(..)"" to retrieve the values.
","
3280
GEOMETRY
3281 3282 3283
GEOMETRY(POINT)
GEOMETRY(POINT Z)
GEOMETRY(POINT Z, 4326)
3284
GEOMETRY(GEOMETRY, 4326)
3285 3286
"

3287
"Data Types","INTERVAL Type","
3288 3289 3290 3291 3292 3293 3294
intervalYearType | intervalMonthType | intervalDayType
    | intervalHourType| intervalMinuteType | intervalSecondType
    | intervalYearToMonthType | intervalDayToHourType
    | intervalDayToMinuteType | intervalDayToSecondType
    | intervalHourToMinuteType | intervalHourToSecondType
    | intervalMinuteToSecondType
","
3295 3296
Interval data type.
There are two classes of intervals. Year-month intervals can store years and months.
3297 3298 3299 3300 3301 3302 3303 3304 3305 3306
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","
3307 3308 3309 3310 3311 3312
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"".
3313
""java.time.Period"" is also supported on Java 8 and later versions.
3314 3315 3316 3317
","
INTERVAL YEAR
"

3318
"Interval Data Types","INTERVAL MONTH Type","
3319 3320 3321 3322 3323 3324
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"".
3325
""java.time.Period"" is also supported on Java 8 and later versions.
3326 3327 3328 3329
","
INTERVAL MONTH
"

3330
"Interval Data Types","INTERVAL DAY Type","
3331 3332 3333 3334 3335 3336 3337 3338 3339 3340 3341
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
"

3342
"Interval Data Types","INTERVAL HOUR Type","
3343 3344 3345 3346 3347 3348 3349 3350 3351 3352 3353
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
"

3354
"Interval Data Types","INTERVAL MINUTE Type","
3355 3356 3357 3358 3359 3360 3361 3362 3363 3364 3365
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
"

3366
"Interval Data Types","INTERVAL SECOND Type","
3367
INTERVAL SECOND [ ( precisionInt [, fractionalPrecisionInt ] ) ]
3368 3369 3370
","
Interval data type.
If precision is specified it should be from 1 to 18, 2 is default.
3371
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
3372 3373 3374 3375 3376 3377 3378

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

3379
"Interval Data Types","INTERVAL YEAR TO MONTH Type","
3380 3381 3382
INTERVAL YEAR [ ( precisionInt ) ] TO MONTH
","
Interval data type.
3383
If leading field precision is specified it should be from 1 to 18, 2 is default.
3384 3385

Mapped to ""org.h2.api.Interval"".
3386
""java.time.Period"" is also supported on Java 8 and later versions.
3387 3388 3389 3390
","
INTERVAL YEAR TO MONTH
"

3391
"Interval Data Types","INTERVAL DAY TO HOUR Type","
3392 3393 3394
INTERVAL DAY [ ( precisionInt ) ] TO HOUR
","
Interval data type.
3395
If leading field precision is specified it should be from 1 to 18, 2 is default.
3396 3397 3398 3399 3400 3401 3402

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

3403
"Interval Data Types","INTERVAL DAY TO MINUTE Type","
3404 3405 3406
INTERVAL DAY [ ( precisionInt ) ] TO MINUTE
","
Interval data type.
3407
If leading field precision is specified it should be from 1 to 18, 2 is default.
3408 3409 3410 3411 3412 3413 3414

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

3415
"Interval Data Types","INTERVAL DAY TO SECOND Type","
3416
INTERVAL DAY [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3417 3418
","
Interval data type.
3419 3420
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.
3421 3422 3423 3424 3425 3426 3427

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

3428
"Interval Data Types","INTERVAL HOUR TO MINUTE Type","
3429 3430 3431
INTERVAL HOUR [ ( precisionInt ) ] TO MINUTE
","
Interval data type.
3432
If leading field precision is specified it should be from 1 to 18, 2 is default.
3433 3434 3435 3436 3437 3438 3439

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

3440
"Interval Data Types","INTERVAL HOUR TO SECOND Type","
3441
INTERVAL HOUR [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3442 3443
","
Interval data type.
3444 3445
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.
3446 3447 3448 3449 3450 3451 3452

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

3453
"Interval Data Types","INTERVAL MINUTE TO SECOND Type","
3454
INTERVAL MINUTE [ ( precisionInt ) ] TO SECOND [ ( fractionalPrecisionInt ) ]
3455 3456
","
Interval data type.
3457 3458
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.
3459 3460 3461 3462 3463 3464 3465

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
3466
"Functions (Aggregate)","AVG","
3467
AVG ( [ DISTINCT|ALL ] { numeric } )
3468
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3469
","
3470 3471
The average (mean) value.
If no rows are selected, the result is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
3472
Aggregates are only allowed in select statements.
3473
The returned value is of the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
3474 3475 3476 3477
","
AVG(X)
"

3478
"Functions (Aggregate)","BIT_AND","
3479
BIT_AND(expression)
3480
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3481 3482 3483 3484 3485 3486 3487 3488 3489
","
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","
3490
BIT_OR(expression)
3491
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3492 3493 3494 3495 3496 3497 3498 3499
","
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)
"

3500 3501
"Functions (Aggregate)","EVERY","
{EVERY|BOOL_AND}(boolean)
3502
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3503
","
3504 3505 3506
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
3507
","
3508
EVERY(ID>10)
Thomas Mueller's avatar
Thomas Mueller committed
3509 3510
"

3511 3512
"Functions (Aggregate)","ANY","
{ANY|SOME|BOOL_OR}(boolean)
3513
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3514
","
3515 3516 3517
Returns true if any expression is true.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
3518 3519 3520 3521

Note that if ANY or SOME aggregate function is placed on the right side of comparison operation
and argument of this function is a subquery additional parentheses around aggregate function are required,
otherwise it will be parsed as quantified comparison predicate.
Thomas Mueller's avatar
Thomas Mueller committed
3522
","
3523
ANY(NAME LIKE 'W%')
3524
A = (ANY((SELECT B FROM T)))
Thomas Mueller's avatar
Thomas Mueller committed
3525 3526 3527
"

"Functions (Aggregate)","COUNT","
3528
COUNT( { * | { [ DISTINCT|ALL ] expression } } )
3529
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3530
","
3531 3532 3533 3534
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
3535 3536 3537 3538 3539
","
COUNT(*)
"

"Functions (Aggregate)","GROUP_CONCAT","
3540
GROUP_CONCAT ( [ DISTINCT|ALL ] string
3541
[ ORDER BY { expression [ ASC | DESC ] } [,...] ]
3542
[ SEPARATOR expression ] )
3543
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3544
","
3545 3546 3547 3548
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.
3549
If ORDER BY is not specified order of strings is not determined.
3550 3551 3552
When this aggregate is used with OVER clause that contains ORDER BY subclause
it does not enforce exact order of strings.
This aggregate needs additional own ORDER BY clause to make it deterministic.
3553
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3554 3555
","
GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ')
3556
GROUP_CONCAT(ID ORDER BY ID SEPARATOR ', ') OVER (ORDER BY ID)
Thomas Mueller's avatar
Thomas Mueller committed
3557 3558
"

3559
"Functions (Aggregate)","ARRAY_AGG","
3560
ARRAY_AGG ( [ DISTINCT|ALL ] string
3561
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] )
3562
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3563 3564 3565 3566
","
Aggregate the value into an array.
This method returns an array.
If no rows are selected, the result is NULL.
3567
If ORDER BY is not specified order of values is not determined.
3568 3569 3570
When this aggregate is used with OVER clause that contains ORDER BY subclause
it does not enforce exact order of values.
This aggregate needs additional own ORDER BY clause to make it deterministic.
3571 3572 3573
Aggregates are only allowed in select statements.
","
ARRAY_AGG(NAME ORDER BY ID)
3574
ARRAY_AGG(ID ORDER BY ID) OVER (ORDER BY ID)
3575 3576
"

Thomas Mueller's avatar
Thomas Mueller committed
3577
"Functions (Aggregate)","MAX","
3578
MAX(value)
3579
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3580
","
3581 3582 3583 3584
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
3585 3586 3587 3588 3589
","
MAX(NAME)
"

"Functions (Aggregate)","MIN","
3590
MIN(value)
3591
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3592
","
3593 3594 3595 3596
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
3597 3598 3599 3600 3601
","
MIN(NAME)
"

"Functions (Aggregate)","SUM","
3602
SUM( [ DISTINCT|ALL ] { numeric } )
3603
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3604
","
3605 3606 3607
The sum of all values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
3608
The data type of the returned value depends on the parameter data type like this:
Thomas Mueller's avatar
Thomas Mueller committed
3609
""BOOLEAN, TINYINT, SMALLINT, INT -> BIGINT, BIGINT -> DECIMAL, REAL -> DOUBLE""
Thomas Mueller's avatar
Thomas Mueller committed
3610 3611 3612 3613 3614
","
SUM(X)
"

"Functions (Aggregate)","SELECTIVITY","
3615
SELECTIVITY(value)
3616
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3617
","
3618 3619 3620 3621 3622
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
3623 3624 3625 3626 3627
","
SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000
"

"Functions (Aggregate)","STDDEV_POP","
3628
STDDEV_POP( [ DISTINCT|ALL ] numeric )
3629
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3630
","
3631 3632 3633
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
3634 3635 3636 3637 3638 3639
Aggregates are only allowed in select statements.
","
STDDEV_POP(X)
"

"Functions (Aggregate)","STDDEV_SAMP","
3640
STDDEV_SAMP( [ DISTINCT|ALL ] numeric )
3641
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3642
","
3643 3644 3645
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
3646 3647 3648 3649 3650 3651
Aggregates are only allowed in select statements.
","
STDDEV(X)
"

"Functions (Aggregate)","VAR_POP","
3652
VAR_POP( [ DISTINCT|ALL ] numeric )
3653
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3654
","
3655 3656 3657 3658
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
3659 3660 3661 3662 3663
","
VAR_POP(X)
"

"Functions (Aggregate)","VAR_SAMP","
3664
VAR_SAMP( [ DISTINCT|ALL ] numeric )
3665
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3666
","
3667 3668 3669 3670
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
3671 3672 3673 3674
","
VAR_SAMP(X)
"

3675
"Functions (Aggregate)","MEDIAN","
3676
MEDIAN( [ DISTINCT|ALL ] value )
3677
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3678 3679 3680
","
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.
3681
Interpolation is only supported for numeric, date-time, and interval data types.
3682 3683 3684 3685 3686 3687 3688
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)
"

3689
"Functions (Aggregate)","MODE","
3690 3691
{ MODE( value ) [ ORDER BY expression [ ASC | DESC ] ] }
    | { MODE() WITHIN GROUP(ORDER BY expression [ ASC | DESC ]) }
3692
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3693 3694 3695
","
Returns the value that occurs with the greatest frequency.
If there are multiple values with the same frequency only one value will be returned.
3696 3697 3698 3699 3700
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.
3701 3702 3703 3704 3705
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)
3706
MODE(X ORDER BY X)
3707
MODE() WITHIN GROUP(ORDER BY X)
3708 3709
"

3710
"Functions (Aggregate)","ENVELOPE","
3711
ENVELOPE( value )
3712
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3713 3714 3715 3716 3717 3718 3719
","
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.
","
3720
ENVELOPE(X)
3721 3722
"

Thomas Mueller's avatar
Thomas Mueller committed
3723
"Functions (Numeric)","ABS","
3724
ABS(numeric|interval)
Thomas Mueller's avatar
Thomas Mueller committed
3725
","
3726
Returns the absolute value of a specified value.
3727
The returned value is of the same data type as the parameter.
3728 3729 3730 3731 3732 3733 3734

Note that TINYINT, SMALLINT, INT, and BIGINT data types cannot represent absolute values
of their minimum negative values, because they have more negative values than positive.
For example, for INT data type allowed values are from -2147483648 to 2147483647.
ABS(-2147483648) should be 2147483648, but this value is not allowed for this data type.
It leads to an exception.
To avoid it cast argument of this function to a higher data type.
Thomas Mueller's avatar
Thomas Mueller committed
3735
","
3736 3737
ABS(VALUE)
ABS(CAST(VALUE AS BIGINT))
Thomas Mueller's avatar
Thomas Mueller committed
3738 3739 3740
"

"Functions (Numeric)","ACOS","
Thomas Mueller's avatar
Thomas Mueller committed
3741
ACOS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3742
","
Thomas Mueller's avatar
Thomas Mueller committed
3743 3744
Calculate the arc cosine.
See also Java ""Math.acos"".
3745
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3746 3747 3748 3749 3750
","
ACOS(D)
"

"Functions (Numeric)","ASIN","
Thomas Mueller's avatar
Thomas Mueller committed
3751
ASIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3752
","
Thomas Mueller's avatar
Thomas Mueller committed
3753 3754
Calculate the arc sine.
See also Java ""Math.asin"".
3755
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3756 3757 3758 3759 3760
","
ASIN(D)
"

"Functions (Numeric)","ATAN","
Thomas Mueller's avatar
Thomas Mueller committed
3761
ATAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3762
","
Thomas Mueller's avatar
Thomas Mueller committed
3763 3764
Calculate the arc tangent.
See also Java ""Math.atan"".
3765
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3766 3767 3768 3769 3770
","
ATAN(D)
"

"Functions (Numeric)","COS","
Thomas Mueller's avatar
Thomas Mueller committed
3771
COS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3772
","
Thomas Mueller's avatar
Thomas Mueller committed
3773 3774
Calculate the trigonometric cosine.
See also Java ""Math.cos"".
3775
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3776 3777 3778 3779
","
COS(ANGLE)
"

3780
"Functions (Numeric)","COSH","
Thomas Mueller's avatar
Thomas Mueller committed
3781
COSH(numeric)
3782 3783 3784 3785 3786 3787 3788 3789
","
Calculate the hyperbolic cosine.
See also Java ""Math.cosh"".
This method returns a double.
","
COSH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3790
"Functions (Numeric)","COT","
Thomas Mueller's avatar
Thomas Mueller committed
3791
COT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3792
","
Thomas Mueller's avatar
Thomas Mueller committed
3793
Calculate the trigonometric cotangent (""1/TAN(ANGLE)"").
3794
See also Java ""Math.*"" functions.
3795
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3796 3797 3798 3799 3800
","
COT(ANGLE)
"

"Functions (Numeric)","SIN","
Thomas Mueller's avatar
Thomas Mueller committed
3801
SIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3802
","
Thomas Mueller's avatar
Thomas Mueller committed
3803 3804
Calculate the trigonometric sine.
See also Java ""Math.sin"".
3805
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3806 3807 3808 3809
","
SIN(ANGLE)
"

3810
"Functions (Numeric)","SINH","
Thomas Mueller's avatar
Thomas Mueller committed
3811
SINH(numeric)
3812 3813 3814 3815 3816 3817 3818 3819
","
Calculate the hyperbolic sine.
See also Java ""Math.sinh"".
This method returns a double.
","
SINH(ANGLE)
"

Thomas Mueller's avatar
Thomas Mueller committed
3820
"Functions (Numeric)","TAN","
Thomas Mueller's avatar
Thomas Mueller committed
3821
TAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3822
","
Thomas Mueller's avatar
Thomas Mueller committed
3823 3824
Calculate the trigonometric tangent.
See also Java ""Math.tan"".
3825
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3826 3827 3828 3829
","
TAN(ANGLE)
"

3830
"Functions (Numeric)","TANH","
Thomas Mueller's avatar
Thomas Mueller committed
3831
TANH(numeric)
3832 3833 3834 3835 3836 3837 3838 3839
","
Calculate the hyperbolic tangent.
See also Java ""Math.tanh"".
This method returns a double.
","
TANH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3840
"Functions (Numeric)","ATAN2","
Thomas Mueller's avatar
Thomas Mueller committed
3841
ATAN2(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3842
","
Thomas Mueller's avatar
Thomas Mueller committed
3843
Calculate the angle when converting the rectangular coordinates to polar coordinates.
3844
See also Java ""Math.atan2"".
3845
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3846 3847 3848 3849 3850
","
ATAN2(X, Y)
"

"Functions (Numeric)","BITAND","
3851
BITAND(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3852
","
3853 3854
The bitwise AND operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3855 3856 3857 3858 3859
See also Java operator &.
","
BITAND(A, B)
"

3860 3861 3862 3863 3864 3865 3866 3867 3868 3869 3870
"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
3871
"Functions (Numeric)","BITOR","
3872
BITOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3873
","
3874 3875
The bitwise OR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3876 3877 3878 3879 3880 3881
See also Java operator |.
","
BITOR(A, B)
"

"Functions (Numeric)","BITXOR","
3882
BITXOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3883
","
3884 3885
The bitwise XOR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3886 3887 3888 3889 3890 3891
See also Java operator ^.
","
BITXOR(A, B)
"

"Functions (Numeric)","MOD","
3892
MOD(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3893
","
3894 3895
The modulo operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3896 3897 3898 3899 3900 3901
See also Java operator %.
","
MOD(A, B)
"

"Functions (Numeric)","CEILING","
Thomas Mueller's avatar
Thomas Mueller committed
3902
{ CEILING | CEIL } (numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3903
","
3904
See also Java ""Math.ceil"".
3905
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3906
","
3907
CEIL(A)
Thomas Mueller's avatar
Thomas Mueller committed
3908 3909 3910
"

"Functions (Numeric)","DEGREES","
Thomas Mueller's avatar
Thomas Mueller committed
3911
DEGREES(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3912
","
3913
See also Java ""Math.toDegrees"".
3914
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3915 3916 3917 3918 3919
","
DEGREES(A)
"

"Functions (Numeric)","EXP","
Thomas Mueller's avatar
Thomas Mueller committed
3920
EXP(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3921
","
3922
See also Java ""Math.exp"".
3923
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3924 3925 3926 3927 3928
","
EXP(A)
"

"Functions (Numeric)","FLOOR","
Thomas Mueller's avatar
Thomas Mueller committed
3929
FLOOR(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3930
","
3931
See also Java ""Math.floor"".
3932
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3933 3934 3935 3936
","
FLOOR(A)
"

3937 3938
"Functions (Numeric)","LN","
{LN|LOG}(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3939
","
3940
Calculates the natural (base e) logarithm as a double value.
3941
In the PostgreSQL mode, LOG(x) is base 10.
3942
See also Java ""Math.log"".
Thomas Mueller's avatar
Thomas Mueller committed
3943
","
3944
LN(A)
Thomas Mueller's avatar
Thomas Mueller committed
3945 3946 3947
"

"Functions (Numeric)","LOG10","
Thomas Mueller's avatar
Thomas Mueller committed
3948
LOG10(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3949
","
3950
Calculates the base 10 logarithm as a double value.
3951
See also Java ""Math.log10"".
Thomas Mueller's avatar
Thomas Mueller committed
3952 3953 3954 3955
","
LOG10(A)
"

3956 3957 3958 3959 3960 3961 3962 3963 3964 3965 3966 3967 3968
"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
3969
"Functions (Numeric)","RADIANS","
Thomas Mueller's avatar
Thomas Mueller committed
3970
RADIANS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3971
","
3972
See also Java ""Math.toRadians"".
3973
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3974 3975 3976 3977 3978
","
RADIANS(A)
"

"Functions (Numeric)","SQRT","
Thomas Mueller's avatar
Thomas Mueller committed
3979
SQRT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3980
","
3981
See also Java ""Math.sqrt"".
3982
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3983 3984 3985 3986 3987
","
SQRT(A)
"

"Functions (Numeric)","PI","
3988
PI()
Thomas Mueller's avatar
Thomas Mueller committed
3989
","
3990
See also Java ""Math.PI"".
3991
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3992 3993 3994 3995 3996
","
PI()
"

"Functions (Numeric)","POWER","
Thomas Mueller's avatar
Thomas Mueller committed
3997
POWER(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3998
","
3999
See also Java ""Math.pow"".
Thomas Mueller's avatar
Thomas Mueller committed
4000
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
4001 4002 4003 4004 4005
","
POWER(A, B)
"

"Functions (Numeric)","RAND","
4006
{ RAND | RANDOM } ( [ int ] )
Thomas Mueller's avatar
Thomas Mueller committed
4007 4008 4009
","
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
4010
This method returns a double between 0 (including) and 1 (excluding).
Thomas Mueller's avatar
Thomas Mueller committed
4011 4012 4013 4014 4015
","
RAND()
"

"Functions (Numeric)","RANDOM_UUID","
4016
{ RANDOM_UUID | UUID } ()
Thomas Mueller's avatar
Thomas Mueller committed
4017 4018
","
Returns a new UUID with 122 pseudo random bits.
Thomas Mueller's avatar
Thomas Mueller committed
4019 4020 4021 4022 4023

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
4024 4025 4026 4027 4028
","
RANDOM_UUID()
"

"Functions (Numeric)","ROUND","
4029
ROUND(numeric [, digitsInt])
Thomas Mueller's avatar
Thomas Mueller committed
4030
","
4031
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
4032
This method returns a numeric (the same type as the input).
Thomas Mueller's avatar
Thomas Mueller committed
4033 4034 4035 4036 4037
","
ROUND(VALUE, 2)
"

"Functions (Numeric)","ROUNDMAGIC","
Thomas Mueller's avatar
Thomas Mueller committed
4038
ROUNDMAGIC(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
4039
","
4040 4041 4042
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.
4043
The value is converted to a String internally, and then the last 4 characters are checked.
4044 4045
'000x' becomes '0000' and '999x' becomes '999999', which is rounded automatically.
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
4046 4047 4048 4049 4050
","
ROUNDMAGIC(VALUE/3*3)
"

"Functions (Numeric)","SECURE_RAND","
4051
SECURE_RAND(int)
Thomas Mueller's avatar
Thomas Mueller committed
4052 4053
","
Generates a number of cryptographically secure random numbers.
4054
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4055 4056 4057 4058 4059
","
CALL SECURE_RAND(16)
"

"Functions (Numeric)","SIGN","
4060
SIGN(numeric|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4061
","
4062
Returns -1 if the value is smaller than 0, 0 if zero, and otherwise 1.
Thomas Mueller's avatar
Thomas Mueller committed
4063 4064 4065 4066 4067
","
SIGN(VALUE)
"

"Functions (Numeric)","ENCRYPT","
4068
ENCRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
4069
","
4070
Encrypts data using a key.
4071
The supported algorithm is AES.
4072 4073
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4074 4075 4076 4077 4078
","
CALL ENCRYPT('AES', '00', STRINGTOUTF8('Test'))
"

"Functions (Numeric)","DECRYPT","
4079
DECRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
4080
","
4081
Decrypts data using a key.
4082
The supported algorithm is AES.
4083 4084
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4085 4086 4087 4088 4089 4090
","
CALL TRIM(CHAR(0) FROM UTF8TOSTRING(
    DECRYPT('AES', '00', '3fabb4de8f1ee2e97d7793bab2db1116')))
"

"Functions (Numeric)","HASH","
4091
HASH(algorithmString, expression [, iterationInt])
Thomas Mueller's avatar
Thomas Mueller committed
4092
","
4093 4094 4095
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
4096 4097 4098 4099 4100
","
CALL HASH('SHA256', STRINGTOUTF8('Password'), 1000)
"

"Functions (Numeric)","TRUNCATE","
4101 4102
{ TRUNC | TRUNCATE } ( { {numeric, digitsInt}
    | timestamp | timestampWithTimeZone | date | timestampString } )
Thomas Mueller's avatar
Thomas Mueller committed
4103 4104
","
Truncates to a number of digits (to the next value closer to 0).
4105
This method returns a double.
4106
When used with a timestamp, truncates a timestamp to a date (day) value.
4107 4108
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
4109 4110 4111 4112 4113
","
TRUNCATE(VALUE, 2)
"

"Functions (Numeric)","COMPRESS","
4114
COMPRESS(dataBytes [, algorithmString])
Thomas Mueller's avatar
Thomas Mueller committed
4115
","
4116 4117 4118 4119
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
4120 4121 4122 4123 4124
","
COMPRESS(STRINGTOUTF8('Test'))
"

"Functions (Numeric)","EXPAND","
4125
EXPAND(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
4126 4127
","
Expands data that was compressed using the COMPRESS function.
4128
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4129 4130 4131 4132 4133
","
UTF8TOSTRING(EXPAND(COMPRESS(STRINGTOUTF8('Test'))))
"

"Functions (Numeric)","ZERO","
4134
ZERO()
Thomas Mueller's avatar
Thomas Mueller committed
4135 4136 4137 4138 4139 4140 4141
","
Returns the value 0. This function can be used even if numeric literals are disabled.
","
ZERO()
"

"Functions (String)","ASCII","
4142
ASCII(string)
Thomas Mueller's avatar
Thomas Mueller committed
4143 4144
","
Returns the ASCII value of the first character in the string.
4145
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4146 4147 4148 4149
","
ASCII('Hi')
"
"Functions (String)","BIT_LENGTH","
4150
BIT_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
4151
","
4152 4153 4154
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
4155 4156 4157 4158 4159
","
BIT_LENGTH(NAME)
"

"Functions (String)","LENGTH","
4160
{ LENGTH | CHAR_LENGTH | CHARACTER_LENGTH } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4161
","
4162 4163 4164
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
4165 4166 4167 4168 4169
","
LENGTH(NAME)
"

"Functions (String)","OCTET_LENGTH","
4170
OCTET_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
4171
","
4172 4173 4174 4175
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
4176 4177 4178 4179 4180
","
OCTET_LENGTH(NAME)
"

"Functions (String)","CHAR","
4181
{ CHAR | CHR } ( int )
Thomas Mueller's avatar
Thomas Mueller committed
4182 4183
","
Returns the character that represents the ASCII value.
4184
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4185 4186 4187 4188 4189
","
CHAR(65)
"

"Functions (String)","CONCAT","
4190
CONCAT(string, string [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4191 4192
","
Combines strings.
Thomas Mueller's avatar
Thomas Mueller committed
4193
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
4194
and do not cause the result to become NULL.
4195
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4196 4197 4198 4199
","
CONCAT(NAME, '!')
"

4200 4201 4202 4203
"Functions (String)","CONCAT_WS","
CONCAT_WS(separatorString, string, string [,...])
","
Combines strings with separator.
Thomas Mueller's avatar
Thomas Mueller committed
4204
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
4205
and do not cause the result to become NULL.
4206 4207 4208 4209 4210
This method returns a string.
","
CONCAT_WS(',', NAME, '!')
"

Thomas Mueller's avatar
Thomas Mueller committed
4211
"Functions (String)","DIFFERENCE","
4212
DIFFERENCE(string, string)
Thomas Mueller's avatar
Thomas Mueller committed
4213 4214
","
Returns the difference between the sounds of two strings.
4215 4216 4217 4218 4219
The difference is calculated as a number of matched characters
in the same positions in SOUNDEX representations of arguments.
This method returns an int between 0 and 4 inclusive, or null if any of its parameters is null.
Note that value of 0 means that strings are not similar to each other.
Value of 4 means that strings are fully similar to each other (have the same SOUNDEX representation).
Thomas Mueller's avatar
Thomas Mueller committed
4220 4221 4222 4223 4224
","
DIFFERENCE(T1.NAME, T2.NAME)
"

"Functions (String)","HEXTORAW","
4225
HEXTORAW(string)
Thomas Mueller's avatar
Thomas Mueller committed
4226
","
4227 4228
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
4229 4230 4231 4232 4233
","
HEXTORAW(DATA)
"

"Functions (String)","RAWTOHEX","
4234
RAWTOHEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
4235
","
4236 4237 4238
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
4239 4240 4241 4242 4243
","
RAWTOHEX(DATA)
"

"Functions (String)","INSTR","
4244
INSTR(string, searchString, [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
4245
","
4246
Returns the location of a search string in a string.
4247 4248 4249
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
4250
Please note this function is case sensitive, even if the parameters are not.
Thomas Mueller's avatar
Thomas Mueller committed
4251 4252 4253 4254 4255
","
INSTR(EMAIL,'@')
"

"Functions (String)","INSERT Function","
4256
INSERT(originalString, startInt, lengthInt, addString)
Thomas Mueller's avatar
Thomas Mueller committed
4257
","
4258 4259 4260
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
4261 4262 4263 4264 4265
","
INSERT(NAME, 1, 1, ' ')
"

"Functions (String)","LOWER","
4266
{ LOWER | LCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4267 4268 4269 4270 4271 4272 4273
","
Converts a string to lowercase.
","
LOWER(NAME)
"

"Functions (String)","UPPER","
4274
{ UPPER | UCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4275 4276 4277 4278 4279 4280 4281
","
Converts a string to uppercase.
","
UPPER(NAME)
"

"Functions (String)","LEFT","
4282
LEFT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4283 4284 4285 4286 4287 4288 4289
","
Returns the leftmost number of characters.
","
LEFT(NAME, 3)
"

"Functions (String)","RIGHT","
4290
RIGHT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4291 4292 4293 4294 4295 4296 4297
","
Returns the rightmost number of characters.
","
RIGHT(NAME, 3)
"

"Functions (String)","LOCATE","
4298
LOCATE(searchString, string [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
4299
","
4300 4301 4302 4303
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
4304 4305 4306 4307 4308
","
LOCATE('.', NAME)
"

"Functions (String)","POSITION","
4309
POSITION(searchString, string)
Thomas Mueller's avatar
Thomas Mueller committed
4310 4311 4312 4313 4314 4315 4316
","
Returns the location of a search string in a string. See also LOCATE.
","
POSITION('.', NAME)
"

"Functions (String)","LPAD","
4317
LPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
4318
","
4319 4320 4321
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
4322 4323 4324 4325 4326
","
LPAD(AMOUNT, 10, '*')
"

"Functions (String)","RPAD","
4327
RPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
4328
","
4329 4330 4331
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
4332 4333 4334 4335 4336
","
RPAD(TEXT, 10, '-')
"

"Functions (String)","LTRIM","
4337
LTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
4338 4339 4340 4341 4342 4343 4344
","
Removes all leading spaces from a string.
","
LTRIM(NAME)
"

"Functions (String)","RTRIM","
4345
RTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
4346 4347 4348 4349 4350 4351 4352
","
Removes all trailing spaces from a string.
","
RTRIM(NAME)
"

"Functions (String)","TRIM","
4353
TRIM ( [ { LEADING | TRAILING | BOTH } [ string ] FROM ] string )
Thomas Mueller's avatar
Thomas Mueller committed
4354
","
4355 4356
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
4357 4358 4359 4360 4361
","
TRIM(BOTH '_' FROM NAME)
"

"Functions (String)","REGEXP_REPLACE","
4362
REGEXP_REPLACE(inputString, regexString, replacementString [, flagsString])
Thomas Mueller's avatar
Thomas Mueller committed
4363
","
4364
Replaces each substring that matches a regular expression.
4365
For details, see the Java ""String.replaceAll()"" method.
4366 4367 4368 4369 4370 4371 4372 4373 4374 4375 4376 4377 4378 4379
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
4380 4381
","
REGEXP_REPLACE('Hello    World', ' +', ' ')
4382
REGEXP_REPLACE('Hello WWWWorld', 'w+', 'W', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
4383 4384
"

4385 4386 4387 4388
"Functions (String)","REGEXP_LIKE","
REGEXP_LIKE(inputString, regexString [, flagsString])
","
Matches string to a regular expression.
4389 4390 4391 4392 4393 4394 4395 4396 4397 4398 4399 4400 4401 4402 4403
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)

4404 4405
","
REGEXP_LIKE('Hello    World', '[A-Z ]*', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
4406 4407 4408
"

"Functions (String)","REPEAT","
4409
REPEAT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4410 4411 4412 4413 4414 4415 4416
","
Returns a string repeated some number of times.
","
REPEAT(NAME || ' ', 10)
"

"Functions (String)","REPLACE","
4417
REPLACE(string, searchString [, replacementString])
Thomas Mueller's avatar
Thomas Mueller committed
4418
","
4419 4420
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.
4421
If any parameter is null, the result is null.
Thomas Mueller's avatar
Thomas Mueller committed
4422 4423 4424 4425 4426
","
REPLACE(NAME, ' ')
"

"Functions (String)","SOUNDEX","
4427
SOUNDEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
4428
","
4429
Returns a four character code representing the sound of a string.
4430 4431
This method returns a string, or null if parameter is null.
See https://en.wikipedia.org/wiki/Soundex for more information.
Thomas Mueller's avatar
Thomas Mueller committed
4432 4433 4434 4435 4436
","
SOUNDEX(NAME)
"

"Functions (String)","SPACE","
4437
SPACE(int)
Thomas Mueller's avatar
Thomas Mueller committed
4438 4439 4440 4441 4442 4443 4444
","
Returns a string consisting of a number of spaces.
","
SPACE(80)
"

"Functions (String)","STRINGDECODE","
4445
STRINGDECODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
4446
","
4447 4448 4449
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
4450 4451 4452 4453 4454
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

"Functions (String)","STRINGENCODE","
4455
STRINGENCODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
4456
","
4457 4458 4459
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
4460 4461 4462 4463 4464
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

"Functions (String)","STRINGTOUTF8","
4465
STRINGTOUTF8(string)
Thomas Mueller's avatar
Thomas Mueller committed
4466 4467
","
Encodes a string to a byte array using the UTF8 encoding format.
4468
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4469 4470 4471 4472 4473
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","SUBSTRING","
4474
{ SUBSTRING | SUBSTR } ( string, startInt [, lengthInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
4475
","
4476
Returns a substring of a string starting at a position.
4477
If the start index is negative, then the start index is relative to the end of the string.
4478
The length is optional.
4479
Also supported is: ""SUBSTRING(string [FROM start] [FOR length])"".
Thomas Mueller's avatar
Thomas Mueller committed
4480
","
4481 4482
CALL SUBSTR('[Hello]', 2, 5);
CALL SUBSTR('Hello World', -5);
Thomas Mueller's avatar
Thomas Mueller committed
4483 4484 4485
"

"Functions (String)","UTF8TOSTRING","
4486
UTF8TOSTRING(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
4487 4488 4489 4490 4491 4492 4493
","
Decodes a byte array in the UTF8 format to a string.
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","XMLATTR","
4494
XMLATTR(nameString, valueString)
Thomas Mueller's avatar
Thomas Mueller committed
4495
","
4496
Creates an XML attribute element of the form ""name=value"".
4497 4498
The value is encoded as XML text.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4499 4500 4501 4502 4503
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'))
"

"Functions (String)","XMLNODE","
4504
XMLNODE(elementString [, attributesString [, contentString [, indentBoolean]]])
Thomas Mueller's avatar
Thomas Mueller committed
4505 4506
","
Create an XML node element.
4507 4508 4509
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.
4510
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4511 4512 4513 4514 4515
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'), 'H2')
"

"Functions (String)","XMLCOMMENT","
4516
XMLCOMMENT(commentString)
Thomas Mueller's avatar
Thomas Mueller committed
4517
","
4518
Creates an XML comment.
4519
Two dashes (""--"") are converted to ""- -"".
4520
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4521 4522 4523 4524 4525
","
CALL XMLCOMMENT('Test')
"

"Functions (String)","XMLCDATA","
4526
XMLCDATA(valueString)
Thomas Mueller's avatar
Thomas Mueller committed
4527
","
4528
Creates an XML CDATA element.
4529
If the value contains ""]]>"", an XML text element is created instead.
4530
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4531 4532 4533 4534 4535
","
CALL XMLCDATA('data')
"

"Functions (String)","XMLSTARTDOC","
4536
XMLSTARTDOC()
Thomas Mueller's avatar
Thomas Mueller committed
4537
","
Thomas Mueller's avatar
Thomas Mueller committed
4538
Returns the XML declaration.
4539
The result is always ""<?xml version=""1.0""?>"".
Thomas Mueller's avatar
Thomas Mueller committed
4540 4541 4542 4543 4544
","
CALL XMLSTARTDOC()
"

"Functions (String)","XMLTEXT","
4545
XMLTEXT(valueString [, escapeNewlineBoolean])
Thomas Mueller's avatar
Thomas Mueller committed
4546 4547
","
Creates an XML text element.
Thomas Mueller's avatar
Thomas Mueller committed
4548
If enabled, newline and linefeed is converted to an XML entity (&#).
4549
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4550 4551 4552 4553
","
CALL XMLTEXT('test')
"

4554
"Functions (String)","TO_CHAR","
4555
TO_CHAR(value [, formatString[, nlsParamString]])
4556 4557 4558 4559 4560 4561
","
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')
"

4562
"Functions (String)","TRANSLATE","
4563
TRANSLATE(value, searchString, replacementString)
4564 4565 4566 4567 4568 4569
","
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
4570
"Functions (Time and Date)","CURRENT_DATE","
4571
{ CURRENT_DATE | CURDATE() | SYSDATE | TODAY }
Thomas Mueller's avatar
Thomas Mueller committed
4572 4573
","
Returns the current date.
4574 4575
These methods always return the same value within a transaction (default)
or within a command depending on database mode.
Thomas Mueller's avatar
Thomas Mueller committed
4576
","
4577
CURRENT_DATE
Thomas Mueller's avatar
Thomas Mueller committed
4578 4579 4580
"

"Functions (Time and Date)","CURRENT_TIME","
4581
CURRENT_TIME [ (int) ]
Thomas Mueller's avatar
Thomas Mueller committed
4582 4583
","
Returns the current time.
4584
The returned value does not have time zone information, because TIME WITH TIME ZONE data type is not supported in H2.
4585 4586 4587 4588
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.
4589 4590
These methods always return the same value within a transaction (default)
or within a command depending on database mode.
Thomas Mueller's avatar
Thomas Mueller committed
4591
","
4592
CURRENT_TIME
4593
CURRENT_TIME(9)
Thomas Mueller's avatar
Thomas Mueller committed
4594 4595 4596
"

"Functions (Time and Date)","CURRENT_TIMESTAMP","
4597
CURRENT_TIMESTAMP [ (int) ]
4598 4599
","
Returns the current timestamp with time zone.
4600
Time zone offset is set to a current time zone offset.
4601
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
4602 4603 4604
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.
4605 4606
This method always returns the same value within a transaction (default)
or within a command depending on database mode.
4607
","
4608 4609
CURRENT_TIMESTAMP
CURRENT_TIMESTAMP(9)
4610 4611
"

4612 4613 4614 4615 4616 4617 4618 4619 4620 4621 4622 4623 4624 4625 4626
"Functions (Time and Date)","LOCALTIME","
{ LOCALTIME [ (int) ] | CURTIME([ int ]) }
","
Returns the current time.
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 (default)
or within a command depending on database mode.
","
LOCALTIME
LOCALTIME(9)
"

4627
"Functions (Time and Date)","LOCALTIMESTAMP","
4628
{ LOCALTIMESTAMP [ (int) ] | NOW( [ int ] ) }
Thomas Mueller's avatar
Thomas Mueller committed
4629
","
4630
Returns the current timestamp without time zone.
4631
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
4632 4633 4634
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.
4635 4636
These methods always return the same value within a transaction (default)
or within a command depending on database mode.
Thomas Mueller's avatar
Thomas Mueller committed
4637
","
4638 4639
LOCALTIMESTAMP
LOCALTIMESTAMP(9)
Thomas Mueller's avatar
Thomas Mueller committed
4640 4641 4642
"

"Functions (Time and Date)","DATEADD","
4643
{ DATEADD| TIMESTAMPADD } (datetimeField, addIntLong, dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4644
","
4645
Adds units to a date-time value. The datetimeField indicates the unit.
4646
Use negative values to subtract units.
4647
addIntLong may be a long value when manipulating milliseconds,
4648
microseconds, or nanoseconds otherwise its range is restricted to int.
4649
This method returns a value with the same type as specified value if unit is compatible with this value.
4650 4651 4652
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
4653 4654 4655 4656 4657
","
DATEADD('MONTH', 1, DATE '2001-01-31')
"

"Functions (Time and Date)","DATEDIFF","
4658
{ DATEDIFF | TIMESTAMPDIFF } (datetimeField, aDateAndTime, bDateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4659
","
4660
Returns the number of crossed unit boundaries between two date/time values.
4661
This method returns a long.
4662
The datetimeField indicates the unit.
4663 4664
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
4665
","
4666
DATEDIFF(YEAR, T1.CREATED, T2.CREATED)
Thomas Mueller's avatar
Thomas Mueller committed
4667 4668 4669
"

"Functions (Time and Date)","DAYNAME","
4670
DAYNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4671 4672 4673 4674 4675 4676 4677
","
Returns the name of the day (in English).
","
DAYNAME(CREATED)
"

"Functions (Time and Date)","DAY_OF_MONTH","
4678
DAY_OF_MONTH(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4679 4680 4681 4682 4683 4684 4685
","
Returns the day of the month (1-31).
","
DAY_OF_MONTH(CREATED)
"

"Functions (Time and Date)","DAY_OF_WEEK","
4686
DAY_OF_WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4687 4688 4689 4690 4691 4692
","
Returns the day of the week (1 means Sunday).
","
DAY_OF_WEEK(CREATED)
"

4693 4694 4695 4696 4697 4698 4699 4700
"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
4701
"Functions (Time and Date)","DAY_OF_YEAR","
4702
DAY_OF_YEAR(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4703 4704 4705 4706 4707 4708 4709
","
Returns the day of the year (1-366).
","
DAY_OF_YEAR(CREATED)
"

"Functions (Time and Date)","EXTRACT","
4710
EXTRACT ( datetimeField FROM { dateAndTime | interval })
Thomas Mueller's avatar
Thomas Mueller committed
4711
","
4712
Returns a value of the specific time unit from a date/time value.
4713 4714
This method returns a numeric value with EPOCH field and
an int for all other fields.
Thomas Mueller's avatar
Thomas Mueller committed
4715 4716 4717 4718 4719
","
EXTRACT(SECOND FROM CURRENT_TIMESTAMP)
"

"Functions (Time and Date)","FORMATDATETIME","
4720
FORMATDATETIME ( dateAndTime, formatString
4721
[ , localeString [ , timeZoneString ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4722
","
4723 4724 4725
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.
4726
For details of the format, see ""java.text.SimpleDateFormat"".
4727 4728
timeZoneString may be specified if dateAndTime is a DATE, TIME or TIMESTAMP.
timeZoneString is ignored if dateAndTime is TIMESTAMP WITH TIME ZONE.
4729
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4730 4731 4732 4733 4734 4735
","
CALL FORMATDATETIME(TIMESTAMP '2001-02-03 04:05:06',
    'EEE, d MMM yyyy HH:mm:ss z', 'en', 'GMT')
"

"Functions (Time and Date)","HOUR","
4736
HOUR(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4737
","
4738
Returns the hour (0-23) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4739 4740 4741 4742 4743
","
HOUR(CREATED)
"

"Functions (Time and Date)","MINUTE","
4744
MINUTE(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4745
","
4746
Returns the minute (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4747 4748 4749 4750 4751
","
MINUTE(CREATED)
"

"Functions (Time and Date)","MONTH","
4752
MONTH(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4753
","
4754
Returns the month (1-12) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4755 4756 4757 4758 4759
","
MONTH(CREATED)
"

"Functions (Time and Date)","MONTHNAME","
4760
MONTHNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4761 4762 4763 4764 4765 4766 4767
","
Returns the name of the month (in English).
","
MONTHNAME(CREATED)
"

"Functions (Time and Date)","PARSEDATETIME","
4768
PARSEDATETIME(string, formatString
4769
[, localeString [, timeZoneString]])
Thomas Mueller's avatar
Thomas Mueller committed
4770
","
4771 4772 4773
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.
4774
For details of the format, see ""java.text.SimpleDateFormat"".
Thomas Mueller's avatar
Thomas Mueller committed
4775 4776 4777 4778 4779 4780
","
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","
4781
QUARTER(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4782
","
4783
Returns the quarter (1-4) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4784 4785 4786 4787 4788
","
QUARTER(CREATED)
"

"Functions (Time and Date)","SECOND","
4789
SECOND(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4790
","
4791
Returns the second (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4792
","
4793
SECOND(CREATED|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4794 4795 4796
"

"Functions (Time and Date)","WEEK","
4797
WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4798
","
4799
Returns the week (1-53) from a date/time value.
4800
This method uses the current system locale.
Thomas Mueller's avatar
Thomas Mueller committed
4801 4802 4803 4804
","
WEEK(CREATED)
"

4805
"Functions (Time and Date)","ISO_WEEK","
4806
ISO_WEEK(dateAndTime)
4807
","
4808
Returns the ISO week (1-53) from a date/time value.
4809
This function uses the ISO definition when
4810 4811 4812 4813 4814 4815
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
4816
"Functions (Time and Date)","YEAR","
4817
YEAR(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4818
","
4819
Returns the year from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4820 4821 4822 4823
","
YEAR(CREATED)
"

4824
"Functions (Time and Date)","ISO_YEAR","
4825
ISO_YEAR(dateAndTime)
4826
","
4827
Returns the ISO week year from a date/time value.
4828 4829 4830 4831
","
ISO_YEAR(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4832
"Functions (System)","ARRAY_GET","
4833
ARRAY_GET(arrayExpression, indexExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4834
","
4835
Returns element at the specified 1-based index from an array.
4836
Returns NULL if there is no such element or array is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
4837
","
4838
CALL ARRAY_GET(ARRAY['Hello', 'World'], 2)
Thomas Mueller's avatar
Thomas Mueller committed
4839 4840 4841
"

"Functions (System)","ARRAY_LENGTH","
Thomas Mueller's avatar
Thomas Mueller committed
4842
ARRAY_LENGTH(arrayExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4843 4844
","
Returns the length of an array.
4845
Returns NULL if the specified array is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
4846
","
4847
CALL ARRAY_LENGTH(ARRAY['Hello', 'World'])
Thomas Mueller's avatar
Thomas Mueller committed
4848 4849
"

4850 4851 4852
"Functions (System)","ARRAY_CONTAINS","
ARRAY_CONTAINS(arrayExpression, value)
","
4853 4854
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.
4855
","
4856
CALL ARRAY_CONTAINS(ARRAY['Hello', 'World'], 'Hello')
4857 4858
"

4859 4860 4861 4862 4863 4864 4865 4866 4867 4868 4869 4870 4871 4872 4873 4874 4875 4876 4877 4878 4879 4880 4881 4882 4883 4884 4885 4886
"Functions (System)","ARRAY_CAT","
ARRAY_CAT(arrayExpression, arrayExpression)
","
Returns the concatenation of two arrays.
Returns NULL if any parameter is NULL.
","
CALL ARRAY_CAT(ARRAY[1, 2], ARRAY[3, 4])
"

"Functions (System)","ARRAY_APPEND","
ARRAY_APPEND(arrayExpression, value)
","
Append an element to the end of an array.
Returns NULL if any parameter is NULL.
","
CALL ARRAY_APPEND(ARRAY[1, 2], 3)
"

"Functions (System)","ARRAY_SLICE","
ARRAY_SLICE(arrayExpression, lowerBoundInt, upperBoundInt)
","
Returns elements from the array as specified by the lower and upper bound parameters.
Both parameters are inclusive and the first element has index 1, i.e. ARRAY_SLICE(a, 2, 2) has only the second element.
Returns NULL if any parameter is NULL or if an index is out of bounds.
","
CALL ARRAY_SLICE(ARRAY[1, 2, 3, 4], 1, 3)
"

Thomas Mueller's avatar
Thomas Mueller committed
4887
"Functions (System)","AUTOCOMMIT","
4888
AUTOCOMMIT()
Thomas Mueller's avatar
Thomas Mueller committed
4889 4890 4891 4892 4893 4894 4895
","
Returns true if auto commit is switched on for this session.
","
AUTOCOMMIT()
"

"Functions (System)","CANCEL_SESSION","
4896
CANCEL_SESSION(sessionInt)
Thomas Mueller's avatar
Thomas Mueller committed
4897
","
4898 4899 4900
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
4901 4902

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4903 4904 4905 4906 4907
","
CANCEL_SESSION(3)
"

"Functions (System)","CASEWHEN Function","
4908
CASEWHEN(boolean, aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
4909 4910
","
Returns 'a' if the boolean expression is true, otherwise 'b'.
4911
Returns the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
4912 4913 4914 4915 4916
","
CASEWHEN(ID=1, 'A', 'B')
"

"Functions (System)","CAST","
4917
CAST(value AS dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4918
","
4919 4920 4921 4922 4923 4924 4925 4926
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.
4927
Note that some data types may need explicitly specified precision to avoid overflow or rounding.
4928 4929 4930 4931
","
CAST(NAME AS INT);
CAST(65535 AS BINARY);
CAST(CAST('FFFF' AS BINARY) AS INT);
4932
CAST(TIMESTAMP '2010-01-01 10:40:00.123456' AS TIME(6))
Thomas Mueller's avatar
Thomas Mueller committed
4933 4934 4935
"

"Functions (System)","COALESCE","
4936
{ COALESCE | NVL } (aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4937 4938 4939 4940 4941 4942 4943
","
Returns the first value that is not null.
","
COALESCE(A, B, C)
"

"Functions (System)","CONVERT","
4944
CONVERT(value, dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4945 4946 4947 4948 4949 4950 4951
","
Converts a value to another data type.
","
CONVERT(NAME, INT)
"

"Functions (System)","CURRVAL","
4952
CURRVAL( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
4953
","
4954 4955 4956 4957 4958
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
4959 4960 4961 4962 4963
","
CURRVAL('TEST_SEQ')
"

"Functions (System)","CSVREAD","
4964
CSVREAD(fileNameString [, columnsString [, csvOptions ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4965
","
4966 4967
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
4968 4969

If the column names are specified (a list of column names separated with the
4970
fieldSeparator), those are used, otherwise (or if they are set to NULL) the first line of
4971 4972 4973 4974 4975
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
4976 4977 4978 4979 4980

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.

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

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

Thomas Mueller's avatar
Thomas Mueller committed
4985
Instead of a file, an URL may be used, for example
4986 4987
""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
4988
To read from HTTP, use the prefix ""http:"" (as in a browser).
4989

Thomas Mueller's avatar
Thomas Mueller committed
4990 4991 4992
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
4993 4994 4995 4996
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
4997 4998 4999 5000
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
5001
SELECT ""Last Name"" FROM CSVREAD('address.csv');
5002
SELECT ""Last Name"" FROM CSVREAD('classpath:/org/acme/data/address.csv');
Thomas Mueller's avatar
Thomas Mueller committed
5003 5004 5005
"

"Functions (System)","CSVWRITE","
5006
CSVWRITE ( fileNameString, queryString [, csvOptions [, lineSepString] ] )
Thomas Mueller's avatar
Thomas Mueller committed
5007
","
5008
Writes a CSV (comma separated values). The file is overwritten if it exists.
Thomas Mueller's avatar
Thomas Mueller committed
5009
If only a file name is specified, it will be written to the current working directory.
5010
For each parameter, NULL means the default value should be used.
Thomas Mueller's avatar
Thomas Mueller committed
5011
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
5012 5013 5014 5015 5016

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
5017
system (system property ""line.separator"").
Thomas Mueller's avatar
Thomas Mueller committed
5018

Thomas Mueller's avatar
Thomas Mueller committed
5019 5020
The returned value is the number or rows written.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5021
","
Thomas Mueller's avatar
Thomas Mueller committed
5022 5023 5024 5025
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
5026 5027 5028
"

"Functions (System)","DATABASE","
5029
DATABASE()
Thomas Mueller's avatar
Thomas Mueller committed
5030 5031 5032 5033 5034 5035 5036
","
Returns the name of the database.
","
CALL DATABASE();
"

"Functions (System)","DATABASE_PATH","
5037
DATABASE_PATH()
Thomas Mueller's avatar
Thomas Mueller committed
5038
","
Thomas Mueller's avatar
Thomas Mueller committed
5039 5040
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
5041 5042 5043 5044
","
CALL DATABASE_PATH();
"

5045
"Functions (System)","DECODE","
Thomas Mueller's avatar
Thomas Mueller committed
5046
DECODE(value, whenValue, thenValue [,...])
5047 5048 5049 5050 5051 5052 5053 5054
","
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');
"

5055
"Functions (System)","DISK_SPACE_USED","
Thomas Mueller's avatar
Thomas Mueller committed
5056
DISK_SPACE_USED(tableNameString)
5057 5058 5059 5060 5061 5062 5063 5064
","
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');
"

5065
"Functions (System)","SIGNAL","
5066
SIGNAL(sqlStateString, messageString)
5067 5068 5069 5070 5071 5072
","
Throw an SQLException with the passed SQLState and reason.
","
CALL SIGNAL('23505', 'Duplicate user ID: ' || user_id);
"

5073 5074 5075 5076 5077 5078 5079 5080 5081 5082 5083 5084 5085 5086 5087 5088 5089
"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
5090
"Functions (System)","FILE_READ","
5091
FILE_READ(fileNameString [,encodingString])
Thomas Mueller's avatar
Thomas Mueller committed
5092 5093 5094 5095
","
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
5096
default character set for this system.
5097 5098 5099 5100

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

Thomas Mueller's avatar
Thomas Mueller committed
5101
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5102 5103 5104 5105 5106
","
SELECT LENGTH(FILE_READ('~/.h2.server.properties')) LEN;
SELECT FILE_READ('http://localhost:8182/stylesheet.css', NULL) CSS;
"

5107
"Functions (System)","FILE_WRITE","
5108
FILE_WRITE(blobValue, fileNameString)
5109 5110 5111 5112 5113 5114 5115 5116
","
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
5117
"Functions (System)","GREATEST","
5118
GREATEST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
5119 5120 5121 5122 5123 5124 5125
","
Returns the largest value that is not NULL, or NULL if all values are NULL.
","
CALL GREATEST(1, 2, 3);
"

"Functions (System)","IDENTITY","
5126
IDENTITY()
Thomas Mueller's avatar
Thomas Mueller committed
5127 5128
","
Returns the last inserted identity value for this session.
5129
This value changes whenever a new sequence number was generated,
5130
even within a trigger or Java function. See also SCOPE_IDENTITY.
5131
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
5132 5133 5134 5135 5136
","
CALL IDENTITY();
"

"Functions (System)","IFNULL","
5137
IFNULL(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
5138 5139 5140 5141 5142 5143 5144
","
Returns the value of 'a' if it is not null, otherwise 'b'.
","
CALL IFNULL(NULL, '');
"

"Functions (System)","LEAST","
5145
LEAST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
5146 5147 5148 5149 5150 5151 5152
","
Returns the smallest value that is not NULL, or NULL if all values are NULL.
","
CALL LEAST(1, 2, 3);
"

"Functions (System)","LOCK_MODE","
5153
LOCK_MODE()
Thomas Mueller's avatar
Thomas Mueller committed
5154 5155
","
Returns the current lock mode. See SET LOCK_MODE.
5156
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5157 5158 5159 5160 5161
","
CALL LOCK_MODE();
"

"Functions (System)","LOCK_TIMEOUT","
5162
LOCK_TIMEOUT()
Thomas Mueller's avatar
Thomas Mueller committed
5163 5164 5165 5166 5167 5168 5169 5170
","
Returns the lock timeout of the current session (in milliseconds).
","
LOCK_TIMEOUT()
"

"Functions (System)","LINK_SCHEMA","
LINK_SCHEMA(targetSchemaString, driverString, urlString,
5171
userString, passwordString, sourceSchemaString)
Thomas Mueller's avatar
Thomas Mueller committed
5172
","
5173 5174 5175 5176 5177
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
5178
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5179 5180 5181 5182 5183
","
CALL LINK_SCHEMA('TEST2', '', 'jdbc:h2:test2', 'sa', 'sa', 'PUBLIC');
"

"Functions (System)","MEMORY_FREE","
5184
MEMORY_FREE()
Thomas Mueller's avatar
Thomas Mueller committed
5185
","
Thomas Mueller's avatar
Thomas Mueller committed
5186
Returns the free memory in KB (where 1024 bytes is a KB).
5187
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5188 5189
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5190 5191 5192 5193 5194
","
MEMORY_FREE()
"

"Functions (System)","MEMORY_USED","
5195
MEMORY_USED()
Thomas Mueller's avatar
Thomas Mueller committed
5196
","
Thomas Mueller's avatar
Thomas Mueller committed
5197
Returns the used memory in KB (where 1024 bytes is a KB).
5198
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5199 5200
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5201 5202 5203 5204 5205
","
MEMORY_USED()
"

"Functions (System)","NEXTVAL","
5206
NEXTVAL ( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
5207
","
5208 5209 5210 5211
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
5212 5213 5214 5215 5216
","
NEXTVAL('TEST_SEQ')
"

"Functions (System)","NULLIF","
5217
NULLIF(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
5218 5219 5220 5221 5222 5223
","
Returns NULL if 'a' is equals to 'b', otherwise 'a'.
","
NULLIF(A, B)
"

5224 5225 5226 5227
"Functions (System)","NVL2","
NVL2(testValue, aValue, bValue)
","
If the test value is null, then 'b' is returned. Otherwise, 'a' is returned.
5228
The data type of the returned value is the data type of 'a' if this is a text type.
5229 5230 5231 5232
","
NVL2(X, 'not null', 'null')
"

Thomas Mueller's avatar
Thomas Mueller committed
5233
"Functions (System)","READONLY","
5234
READONLY()
Thomas Mueller's avatar
Thomas Mueller committed
5235 5236 5237 5238 5239 5240 5241
","
Returns true if the database is read-only.
","
READONLY()
"

"Functions (System)","ROWNUM","
5242
ROWNUM()
Thomas Mueller's avatar
Thomas Mueller committed
5243
","
5244
Returns the number of the current row.
5245
This method returns a long value.
5246
It is supported for SELECT statements, as well as for DELETE and UPDATE.
5247
The first row has the row number 1, and is calculated before ordering and grouping the result set,
5248
but after evaluating index conditions (even when the index conditions are specified in an outer query).
5249
Use the ROW_NUMBER() OVER () function to get row numbers after grouping or in specified order.
Thomas Mueller's avatar
Thomas Mueller committed
5250
","
5251 5252
SELECT ROWNUM(), * FROM TEST;
SELECT ROWNUM(), * FROM (SELECT * FROM TEST ORDER BY NAME);
Thomas Mueller's avatar
Thomas Mueller committed
5253
SELECT ID FROM (SELECT T.*, ROWNUM AS R FROM TEST T) WHERE R BETWEEN 2 AND 3;
Thomas Mueller's avatar
Thomas Mueller committed
5254 5255 5256
"

"Functions (System)","SCHEMA","
5257
SCHEMA()
Thomas Mueller's avatar
Thomas Mueller committed
5258
","
5259
Returns the name of the default schema for this session.
Thomas Mueller's avatar
Thomas Mueller committed
5260 5261 5262 5263
","
CALL SCHEMA()
"

5264 5265 5266
"Functions (System)","SCOPE_IDENTITY","
SCOPE_IDENTITY()
","
5267
Returns the last inserted identity value for this session for the current scope
5268
(the current statement).
5269 5270 5271 5272 5273 5274
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
5275
"Functions (System)","SESSION_ID","
5276
SESSION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
5277
","
5278 5279 5280 5281
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
5282 5283 5284 5285 5286
","
CALL SESSION_ID()
"

"Functions (System)","SET","
5287
SET(@variableName, value)
Thomas Mueller's avatar
Thomas Mueller committed
5288
","
5289 5290 5291
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
5292
When used in a subquery, not all rows might be read depending on the query plan.
Thomas Mueller's avatar
Thomas Mueller committed
5293
This can be used to implement running totals / cumulative sums.
Thomas Mueller's avatar
Thomas Mueller committed
5294 5295 5296 5297 5298
","
SELECT X, SET(@I, IFNULL(@I, 0)+X) RUNNING_TOTAL FROM SYSTEM_RANGE(1, 10)
"

"Functions (System)","TABLE","
5299 5300
{ TABLE | TABLE_DISTINCT }
( { name dataType = array|rowValueExpression } [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
5301 5302 5303
","
Returns the result set. TABLE_DISTINCT removes duplicate rows.
","
5304 5305
SELECT * FROM TABLE(VALUE INT = ARRAY[1, 2]);
SELECT * FROM TABLE(ID INT=(1, 2), NAME VARCHAR=('Hello', 'World'));
Thomas Mueller's avatar
Thomas Mueller committed
5306 5307 5308
"

"Functions (System)","TRANSACTION_ID","
5309
TRANSACTION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
5310
","
5311
Returns the current transaction id for this session.
5312
This method returns NULL if there is no uncommitted change, or if the database is not persisted.
Thomas Mueller's avatar
Thomas Mueller committed
5313
Otherwise a value of the following form is returned:
5314
""logFileId-position-sessionId"".
5315 5316
This method returns a string.
The value is unique across database restarts (values are not re-used).
Thomas Mueller's avatar
Thomas Mueller committed
5317 5318 5319 5320
","
CALL TRANSACTION_ID()
"

5321 5322 5323 5324 5325 5326 5327 5328 5329 5330 5331 5332
"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);
"

5333 5334 5335 5336 5337 5338 5339 5340 5341 5342 5343 5344
"Functions (System)","UNNEST","
UNNEST(array, [,...]) [WITH ORDINALITY]
","
Returns the result set.
Number of columns is equal to number of arguments,
plus one additional column with row number if WITH ORDINALITY is specified.
Number of rows is equal to length of longest specified array.
If multiple arguments are specified and they have different length, cells with missing values will contain null values.
","
SELECT * FROM UNNEST(ARRAY['a', 'b', 'c']);
"

Thomas Mueller's avatar
Thomas Mueller committed
5345
"Functions (System)","USER","
5346
{ USER | CURRENT_USER } ()
Thomas Mueller's avatar
Thomas Mueller committed
5347 5348 5349 5350 5351 5352
","
Returns the name of the current user of this session.
","
CURRENT_USER()
"

5353 5354 5355 5356 5357 5358 5359 5360
"Functions (System)","H2VERSION","
H2VERSION()
","
Returns the H2 version as a String.
","
H2VERSION()
"

5361
"Functions (Window)","ROW_NUMBER","
5362
ROW_NUMBER() OVER windowNameOrSpecification
5363 5364
","
Returns the number of the current row starting with 1.
5365
Window frame clause is not allowed for this function.
5366 5367 5368 5369 5370 5371 5372 5373 5374 5375

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","
5376
RANK() OVER windowNameOrSpecification
5377 5378 5379 5380 5381
","
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.
5382 5383
This function requires window order clause.
Window frame clause is not allowed for this function.
5384 5385 5386 5387 5388 5389 5390 5391 5392

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","
5393
DENSE_RANK() OVER windowNameOrSpecification
5394 5395 5396 5397 5398
","
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.
5399 5400
This function requires window order clause.
Window frame clause is not allowed for this function.
5401 5402 5403 5404

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
5405 5406 5407 5408 5409
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","
5410
PERCENT_RANK() OVER windowNameOrSpecification
5411 5412 5413 5414
","
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.
5415
Note that result is always 0 if window order clause is not specified.
5416
Window frame clause is not allowed for this function.
5417 5418 5419 5420 5421 5422 5423 5424 5425

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","
5426
CUME_DIST() OVER windowNameOrSpecification
5427 5428 5429 5430 5431
","
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.
5432
Note that result is always 1 if window order clause is not specified.
5433
Window frame clause is not allowed for this function.
5434 5435 5436 5437 5438 5439

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;
5440 5441
"

5442
"Functions (Window)","NTILE","
5443
NTILE(long) OVER windowNameOrSpecification
5444 5445
","
Distributes the rows into a specified number of groups.
5446
Number of groups should be a positive long value.
5447 5448 5449
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.
5450 5451
This function requires window order clause.
Window frame clause is not allowed for this function.
5452 5453 5454 5455 5456 5457 5458 5459

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;
"

5460 5461
"Functions (Window)","LEAD","
LEAD(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
5462
OVER windowNameOrSpecification
5463 5464 5465 5466 5467 5468 5469
","
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.
5470 5471
This function requires window order clause.
Window frame clause is not allowed for this function.
5472 5473 5474 5475 5476 5477 5478 5479 5480 5481 5482 5483

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]
5484
OVER windowNameOrSpecification
5485 5486 5487 5488 5489 5490 5491
","
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.
5492 5493
This function requires window order clause.
Window frame clause is not allowed for this function.
5494 5495 5496 5497 5498 5499 5500 5501 5502 5503

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;
"

5504
"Functions (Window)","FIRST_VALUE","
5505 5506
FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
5507 5508 5509 5510 5511 5512 5513 5514 5515 5516 5517 5518
","
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","
5519 5520
LAST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
5521 5522 5523 5524
","
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.
5525 5526
Note that the last value is actually a value in the current group of rows
if window order clause is specified and window frame clause is not specified.
5527 5528 5529 5530 5531

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;
5532 5533 5534 5535
SELECT LAST_VALUE(X) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
    RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
), * FROM TEST;
5536 5537 5538
"

"Functions (Window)","NTH_VALUE","
5539
NTH_VALUE(value, nInt) [FROM {FIRST|LAST}] [{RESPECT|IGNORE} NULLS]
5540
OVER windowNameOrSpecification
5541 5542 5543
","
Returns the value in a row with a specified relative number in a window.
Relative row number must be positive.
5544
If FROM LAST is specified rows a counted backwards from the last row.
5545 5546
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.
5547 5548
Note that the last row is actually a last row in the current group of rows
if window order clause is specified and window frame clause is not specified.
5549 5550 5551 5552 5553

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;
5554 5555 5556 5557
SELECT NTH_VALUE(X) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
    RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
), * FROM TEST;
5558 5559
"

5560 5561 5562 5563 5564
"Functions (Window)","RATIO_TO_REPORT","
RATIO_TO_REPORT(value)
OVER windowNameOrSpecification
","
Returns the ratio of a value to the sum of all values.
5565
If argument is NULL or sum of all values is 0, then the value of function is NULL.
5566
Window ordering and window frame clauses are not allowed for this function.
5567 5568 5569 5570 5571 5572 5573

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 X, RATIO_TO_REPORT(X) OVER (PARTITION BY CATEGORY), CATEGORY FROM TEST;
"

Thomas Mueller's avatar
Thomas Mueller committed
5574 5575 5576 5577 5578 5579 5580 5581 5582 5583 5584 5585 5586 5587 5588
"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)
"