help.csv 170.2 KB
Newer Older
1
# Copyright 2004-2018 H2 Group. Multiple-Licensed under the MPL 2.0,
2
# and the EPL 1.0 (http://h2database.com/html/license.html).
Thomas Mueller's avatar
Thomas Mueller committed
3 4 5
# Initial Developer: H2 Group
"SECTION","TOPIC","SYNTAX","TEXT","EXAMPLE"
"Commands (DML)","SELECT","
6
SELECT [ TOP term [ PERCENT ] [ WITH TIES ] ]
7
[ DISTINCT [ ON ( expression [,...] ) ] | ALL ]
8
selectExpression [,...]
9 10
FROM tableExpression [,...] [ WHERE expression ]
[ GROUP BY expression [,...] ] [ HAVING expression ]
11
[ WINDOW { { windowName AS windowSpecification } [,...] } ]
12 13
[ { UNION [ ALL ] | MINUS | EXCEPT | INTERSECT } select ]
[ ORDER BY order [,...] ]
14 15
[ LIMIT expression [ OFFSET expression ] [ SAMPLE_SIZE rowCountInt ] ]
[ [ OFFSET expression { ROW | ROWS } ]
16
    [ FETCH { FIRST | NEXT } [ expression [ PERCENT ] ] { ROW | ROWS }
17
        { ONLY | WITH TIES } ] [ SAMPLE_SIZE rowCountInt ] ]
18
[ FOR UPDATE ]
Thomas Mueller's avatar
Thomas Mueller committed
19 20
","
Selects data from a table or multiple tables.
21
GROUP BY groups the 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 44 45
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.
When using default MVStore engine only the selected rows are locked as in an UPDATE statement.
With PageStore engine the whole tables are locked.
Thomas Mueller's avatar
Thomas Mueller committed
46 47
","
SELECT * FROM TEST;
48 49 50 51
SELECT * FROM TEST ORDER BY NAME;
SELECT ID, COUNT(*) FROM TEST GROUP BY ID;
SELECT NAME, COUNT(*) FROM TEST GROUP BY NAME HAVING COUNT(*) > 2;
SELECT 'ID' COL, MAX(ID) AS MAX FROM TEST UNION SELECT 'NAME', MAX(NAME) FROM TEST;
52 53
SELECT * FROM TEST OFFSET 1000 ROWS FETCH FIRST 1000 ROWS ONLY;
SELECT A, B FROM TEST ORDER BY A FETCH FIRST 10 ROWS WITH TIES;
Thomas Mueller's avatar
Thomas Mueller committed
54 55 56
SELECT * FROM (SELECT ID, COUNT(*) FROM TEST
    GROUP BY ID UNION SELECT NULL, COUNT(*) FROM TEST)
    ORDER BY 1 NULLS LAST;
57 58
SELECT DISTINCT C1, C2 FROM TEST;
SELECT DISTINCT ON(C1) C1, C2 FROM TEST ORDER BY C1;
Thomas Mueller's avatar
Thomas Mueller committed
59 60 61
"

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

When using DIRECT, then the results from the query are directly applied in the target table without any intermediate step.

When using SORTED, b-tree pages are split at the insertion point. This can improve performance and reduce disk usage.
Thomas Mueller's avatar
Thomas Mueller committed
69 70 71 72 73
","
INSERT INTO TEST VALUES(1, 'Hello')
"

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

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

"Commands (DML)","BACKUP","
BACKUP TO fileNameString
","
Thomas Mueller's avatar
Thomas Mueller committed
96 97
Backs up the database files to a .zip file. Objects are not locked, but
the backup is transactionally consistent because the transaction log is also copied.
Thomas Mueller's avatar
Thomas Mueller committed
98
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
99 100 101 102 103 104 105
","
BACKUP TO 'backup.zip'
"

"Commands (DML)","CALL","
CALL expression
","
Thomas Mueller's avatar
Thomas Mueller committed
106 107 108
Calculates a simple expression. This statement returns a result set with one row,
except if the called function returns a result set itself.
If the called function returns an array, then each element in this array is returned as a column.
Thomas Mueller's avatar
Thomas Mueller committed
109 110 111 112 113
","
CALL 15*25
"

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

"Commands (DML)","MERGE","
125 126
MERGE INTO tableName [ ( columnName [,...] ) ]
[ KEY ( columnName [,...] ) ]
127
{ VALUES { ( { DEFAULT | expression } [,...] ) } [,...] | select }
Thomas Mueller's avatar
Thomas Mueller committed
128 129 130
","
Updates existing rows, and insert rows that don't exist. If no key column is
specified, the primary key columns are used to find the row. If more than one
131
row per new row is affected, an exception is thrown.
Thomas Mueller's avatar
Thomas Mueller committed
132 133 134 135
","
MERGE INTO TEST KEY(ID) VALUES(2, 'World')
"

Owner's avatar
Owner committed
136
"Commands (DML)","MERGE USING","
137 138
MERGE INTO targetTableName [ [AS] targetAlias]
USING { ( select ) | sourceTableName }[ [AS] sourceAlias ]
139
ON expression
140 141 142 143 144 145 146 147
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.

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

"Commands (DDL)","ALTER TABLE ADD","
317
ALTER TABLE [ IF EXISTS ] tableName ADD [ COLUMN ]
318 319
{ [ IF NOT EXISTS ] columnName columnDefinition
    | ( { columnName columnDefinition | constraint } [,...] ) }
320
[ { { BEFORE | AFTER } columnName } | FIRST ]
Thomas Mueller's avatar
Thomas Mueller committed
321
","
Thomas Mueller's avatar
Thomas Mueller committed
322
Adds a new column to a table.
Thomas Mueller's avatar
Thomas Mueller committed
323
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
324 325 326 327 328
","
ALTER TABLE TEST ADD CREATEDATE TIMESTAMP
"

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

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

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

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

368 369 370
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
371

372 373 374 375
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
376

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

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

381
SET NULL sets a column to allow NULL. The row may not be part of a primary key.
Thomas Mueller's avatar
Thomas Mueller committed
382
Single column indexes on this column are dropped.
383 384 385

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

386 387 388
SET INVISIBLE makes the column hidden, i.e. it will not appear in SELECT * results.
SET VISIBLE has the reverse effect.

389 390 391 392
DROP DEFAULT removes the default value of a column.

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

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

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

"Commands (DDL)","ALTER TABLE DROP CONSTRAINT","
419 420
ALTER TABLE [ IF EXISTS ] tableName DROP
{ CONSTRAINT [ IF EXISTS ] constraintName | PRIMARY KEY }
Thomas Mueller's avatar
Thomas Mueller committed
421 422
","
Removes a constraint or a primary key from a table.
Thomas Mueller's avatar
Thomas Mueller committed
423
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
424 425 426 427 428
","
ALTER TABLE TEST DROP CONSTRAINT UNIQUE_NAME
"

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

Thomas Mueller's avatar
Thomas Mueller committed
438
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
439 440 441 442 443
","
ALTER TABLE TEST SET REFERENTIAL_INTEGRITY FALSE
"

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

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

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

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

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

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

Thomas Mueller's avatar
Thomas Mueller committed
522
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
523 524 525 526 527
","
ANALYZE SAMPLE_SIZE 1000
"

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

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

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

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

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

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

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

583
If the first parameter of the Java function is a ""java.sql.Connection"", then a
Thomas Mueller's avatar
Thomas Mueller committed
584 585 586
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.
587

Thomas Mueller's avatar
Thomas Mueller committed
588
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
589
This command commits an open transaction in this connection.
590 591

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

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

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

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

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

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

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

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

659 660 661
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
662 663
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
664
work. Linked tables to the same database share one connection.
665

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

Thomas Mueller's avatar
Thomas Mueller committed
668 669 670
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).

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

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

Thomas Mueller's avatar
Thomas Mueller committed
678
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
679
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
680
","
681 682
CREATE LINKED TABLE LINK('org.h2.Driver', 'jdbc:h2:test2',
    'sa', 'sa', 'TEST');
Thomas Mueller's avatar
Thomas Mueller committed
683 684 685
CREATE LINKED TABLE LINK('', 'jdbc:h2:test2', 'sa', 'sa',
    '(SELECT * FROM TEST WHERE ID>0)');
CREATE LINKED TABLE LINK('javax.naming.InitialContext',
686 687
    'java:comp/env/jdbc/Test', NULL, NULL,
    '(SELECT * FROM TEST WHERE ID>0)');
Thomas Mueller's avatar
Thomas Mueller committed
688 689 690
"

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

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

Thomas Mueller's avatar
Thomas Mueller committed
710
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
711 712 713 714 715
","
CREATE SCHEMA TEST_SCHEMA AUTHORIZATION SA
"

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

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
727

Thomas Mueller's avatar
Thomas Mueller committed
728
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
729 730 731 732 733
","
CREATE SEQUENCE SEQ_ID
"

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

Thomas Mueller's avatar
Thomas Mueller committed
743 744 745 746
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
747
that means memory tables should not get too large.
748

Thomas Mueller's avatar
Thomas Mueller committed
749 750 751 752 753
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,
754
unless the temporary table is created using CREATE CACHED TABLE.
Thomas Mueller's avatar
Thomas Mueller committed
755

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

760 761 762
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.

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

766 767
The column definition is optional if a query is specified.
In that case the column list of the query is used.
768
If the query is specified its results are inserted into created table unless WITH NO DATA is specified.
769

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

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

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

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

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

807
INSTEAD OF triggers are implicitly row based and behave like BEFORE triggers.
808
Only the first such trigger is called. Such triggers on views are supported.
809
They can be used to make views updatable.
810

Thomas Mueller's avatar
Thomas Mueller committed
811 812
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.
813 814
The trigger is called with both 'old' and 'new' set to null.

815 816 817 818
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
819 820
Committing or rolling back a transaction within a trigger is not allowed, except for SELECT triggers.

Thomas Mueller's avatar
Thomas Mueller committed
821 822 823
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.

824 825
QUEUE is implemented for syntax compatibility with HSQL and has no effect.

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

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

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

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

Thomas Mueller's avatar
Thomas Mueller committed
857 858 859 860 861
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.

862 863
Views are not updatable except when using 'instead of' triggers.

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

"Commands (DDL)","DROP AGGREGATE","
871
DROP AGGREGATE [ IF EXISTS ] aggregateName
Thomas Mueller's avatar
Thomas Mueller committed
872
","
Thomas Mueller's avatar
Thomas Mueller committed
873 874 875
Drops an existing user-defined aggregate function.

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

"Commands (DDL)","DROP ALIAS","
882
DROP ALIAS [ IF EXISTS ] existingFunctionAliasName
Thomas Mueller's avatar
Thomas Mueller committed
883
","
Thomas Mueller's avatar
Thomas Mueller committed
884 885 886
Drops an existing function alias.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
887
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
888
","
Thomas Mueller's avatar
Thomas Mueller committed
889
DROP ALIAS MY_SQRT
Thomas Mueller's avatar
Thomas Mueller committed
890 891 892
"

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

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
902 903 904 905 906
","
DROP ALL OBJECTS
"

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

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

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

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

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

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

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

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

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

Thomas Mueller's avatar
Thomas Mueller committed
990
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
991
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
992 993 994 995 996
","
DROP USER TOM
"

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

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

Thomas Mueller's avatar
Thomas Mueller committed
1018
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1019 1020 1021 1022 1023 1024 1025
","
TRUNCATE TABLE TEST
"

"Commands (Other)","CHECKPOINT","
CHECKPOINT
","
Thomas Mueller's avatar
Thomas Mueller committed
1026
Flushes the data to disk.
Thomas Mueller's avatar
Thomas Mueller committed
1027 1028

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

"Commands (Other)","CHECKPOINT SYNC","
CHECKPOINT SYNC
","
Thomas Mueller's avatar
Thomas Mueller committed
1036
Flushes the data to disk and and forces all system buffers be written
Thomas Mueller's avatar
Thomas Mueller committed
1037 1038 1039
to the underlying device.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1040 1041 1042 1043 1044
","
CHECKPOINT SYNC
"

"Commands (Other)","COMMIT","
1045
COMMIT [ WORK ]
Thomas Mueller's avatar
Thomas Mueller committed
1046 1047 1048 1049 1050 1051 1052 1053 1054
","
Commits a transaction.
","
COMMIT
"

"Commands (Other)","COMMIT TRANSACTION","
COMMIT TRANSACTION transactionName
","
Thomas Mueller's avatar
Thomas Mueller committed
1055 1056 1057 1058
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
1059 1060 1061 1062 1063
","
COMMIT TRANSACTION XID_TEST
"

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

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

Thomas Mueller's avatar
Thomas Mueller committed
1087
"Commands (Other)","GRANT ROLE","
1088
GRANT roleName TO { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1089
","
Thomas Mueller's avatar
Thomas Mueller committed
1090 1091 1092
Grants a role to a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1093
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1094 1095 1096 1097 1098
","
GRANT READONLY TO PUBLIC
"

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

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

"Commands (Other)","REVOKE ROLE","
1129
REVOKE roleName FROM { PUBLIC | userName | roleName }
Thomas Mueller's avatar
Thomas Mueller committed
1130
","
Thomas Mueller's avatar
Thomas Mueller committed
1131 1132 1133
Removes a role from a user or role.

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1134
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1135 1136 1137 1138 1139
","
REVOKE READONLY FROM TOM
"

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

"Commands (Other)","SAVEPOINT","
SAVEPOINT savepointName
","
Thomas Mueller's avatar
Thomas Mueller committed
1162 1163
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
1164 1165 1166 1167 1168
","
SAVEPOINT HALF_DONE
"

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

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

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

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

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

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

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

Thomas Mueller's avatar
Thomas Mueller committed
1245
This command is effective immediately, but does not commit an open transaction.
Thomas Mueller's avatar
Thomas Mueller committed
1246 1247 1248 1249
","
SET CLUSTER ''
"

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

1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281
"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
"

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

1305 1306 1307 1308 1309
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).
1310 1311
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.
1312

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

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

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

"Commands (Other)","SET DB_CLOSE_DELAY","
SET DB_CLOSE_DELAY int
","
Thomas Mueller's avatar
Thomas Mueller committed
1355 1356
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
1357 1358 1359 1360
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
1361

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

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

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

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

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

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1414
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1415
","
Thomas Mueller's avatar
Thomas Mueller committed
1416
SET EXCLUSIVE 1
Thomas Mueller's avatar
Thomas Mueller committed
1417 1418 1419
"

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

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

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

1455 1456 1457 1458 1459 1460 1461 1462 1463 1464 1465 1466 1467 1468 1469 1470 1471
"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
"

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

1478
LOG 0 means the transaction log is disabled completely. It is the fastest mode,
1479 1480 1481 1482
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.

1483 1484
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
1485 1486
against power failure is required, but the data must be protected against killing the process.

1487 1488
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
1489 1490
file system, this will also protect against power failure in the majority if cases.

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

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

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

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

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

1542
This is the maximum length of an LOB that is stored with the record itself,
1543 1544
and the default value is 128.

Thomas Mueller's avatar
Thomas Mueller committed
1545
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1546
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1547
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1548 1549 1550 1551 1552 1553 1554
","
SET MAX_LENGTH_INPLACE_LOB 128
"

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

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

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

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

Thomas Mueller's avatar
Thomas Mueller committed
1592
Admin rights are required to execute this command, as it affects all connections.
Thomas Mueller's avatar
Thomas Mueller committed
1593
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1594
This setting is persistent.
Thomas Mueller's avatar
Thomas Mueller committed
1595
It has no effect for in-memory databases.
Thomas Mueller's avatar
Thomas Mueller committed
1596 1597 1598 1599 1600 1601 1602 1603 1604
","
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
1605 1606 1607
operation. The default max size is 100000. 0 means no limit.

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

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

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

"Commands (Other)","SET MULTI_THREADED","
1630
SET MULTI_THREADED { 0 | 1 }
Thomas Mueller's avatar
Thomas Mueller committed
1631
","
1632 1633 1634
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
1635 1636 1637 1638

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

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

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

Thomas Mueller's avatar
Thomas Mueller committed
1666
This command commits an open transaction in this connection.
Thomas Mueller's avatar
Thomas Mueller committed
1667 1668 1669 1670
","
SET PASSWORD 'abcstzri!.5'
"

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

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

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

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

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

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

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

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

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

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

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

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

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

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

1855 1856
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
1857 1858 1859

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,
1860
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
1861 1862

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

1864
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.
1865

Thomas Mueller's avatar
Thomas Mueller committed
1866
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
1867
","
1868
SHUTDOWN COMPACT
Thomas Mueller's avatar
Thomas Mueller committed
1869 1870
"

1871 1872 1873 1874 1875 1876 1877 1878 1879 1880 1881 1882 1883 1884 1885 1886 1887 1888 1889 1890 1891 1892 1893 1894 1895 1896 1897 1898 1899 1900 1901 1902 1903 1904 1905 1906 1907 1908 1909 1910 1911 1912 1913 1914 1915 1916 1917 1918 1919 1920 1921 1922 1923 1924 1925 1926 1927 1928 1929 1930 1931 1932 1933 1934 1935 1936 1937 1938 1939 1940 1941 1942 1943 1944 1945 1946 1947 1948 1949 1950 1951 1952 1953 1954 1955 1956 1957 1958 1959 1960 1961 1962 1963 1964 1965 1966 1967 1968 1969 1970 1971 1972 1973 1974 1975 1976 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
"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).
2003 2004
ISO definition is used when first week of year should have at least four days
and week is started with Monday.
2005 2006 2007 2008 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
","
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
"

2036 2037
"Other Grammar","Alias","
name
Thomas Mueller's avatar
Thomas Mueller committed
2038
","
2039
An alias is a name that is only valid in the context of the statement.
Thomas Mueller's avatar
Thomas Mueller committed
2040
","
2041
A
Thomas Mueller's avatar
Thomas Mueller committed
2042 2043
"

2044 2045
"Other Grammar","And Condition","
condition [ { AND condition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2046
","
2047
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2048
","
2049
ID=1 AND NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2050 2051
"

2052
"Other Grammar","Array","
2053
ARRAY '[' [ expression, [,...] ] ']'
Thomas Mueller's avatar
Thomas Mueller committed
2054
","
2055
An array of values.
Thomas Mueller's avatar
Thomas Mueller committed
2056
","
2057 2058 2059
ARRAY[1, 2]
ARRAY[1]
ARRAY[]
Thomas Mueller's avatar
Thomas Mueller committed
2060 2061
"

2062 2063
"Other Grammar","Boolean","
TRUE | FALSE
2064
","
2065
A boolean value.
2066
","
2067
TRUE
2068 2069
"

2070 2071
"Other Grammar","Bytes","
X'hex'
Thomas Mueller's avatar
Thomas Mueller committed
2072
","
2073
A binary value. The hex value is not case sensitive.
Thomas Mueller's avatar
Thomas Mueller committed
2074
","
2075
X'01FF'
Thomas Mueller's avatar
Thomas Mueller committed
2076 2077
"

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

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

"Other Grammar","Cipher","
2099
AES
2100
","
2101
Only the algorithm AES (""AES-128"") is supported currently.
2102 2103
","
AES
Thomas Mueller's avatar
Thomas Mueller committed
2104 2105
"

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

2122 2123 2124 2125 2126
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
2127

2128 2129 2130
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
2131 2132
The options PRIMARY KEY, UNIQUE, and CHECK are not supported for ALTER statements.

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

2138
","
Thomas Mueller's avatar
Thomas Mueller committed
2139 2140 2141
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);
2142 2143
"

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

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

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

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

2182 2183 2184 2185 2186 2187
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
2188
left size of condition and at least one row from a subquery returns TRUE.
2189 2190 2191 2192 2193
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
2194
The conditions ""IS [ NOT ]"" and ""IS [ NOT ] DISTINCT FROM"" are null-safe, meaning
2195 2196
NULL is considered the same as NULL, and the condition never evaluates to NULL.

Thomas Mueller's avatar
Thomas Mueller committed
2197 2198 2199 2200 2201
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).
2202 2203 2204
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.
2205

2206 2207
ILIKE does a case-insensitive compare.

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

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

2232 2233
"Other Grammar","Constraint Name Definition","
CONSTRAINT [ IF NOT EXISTS ] newConstraintName
Thomas Mueller's avatar
Thomas Mueller committed
2234
","
2235
Defines a constraint name.
Thomas Mueller's avatar
Thomas Mueller committed
2236
","
2237
CONSTRAINT CONST_ID
Thomas Mueller's avatar
Thomas Mueller committed
2238 2239
"

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

2251
""caseSensitiveColumnNames"" (true or false; disabled by default),
2252

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

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

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

thomasmueller's avatar
thomasmueller committed
2259
""fieldSeparator"" (a comma by default),
2260

2261
""lineComment"" (disabled by default),
2262

2263
""lineSeparator"" (the line separator used for writing; ignored for reading),
2264

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

2268
""preserveWhitespace"" (true or false; disabled by default),
2269

2270
""writeColumnHeader"" (true or false; enabled by default).
2271

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

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

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

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

2319 2320
"Other Grammar","Digit","
0-9
Thomas Mueller's avatar
Thomas Mueller committed
2321
","
2322
A digit.
Thomas Mueller's avatar
Thomas Mueller committed
2323
","
2324
0
Thomas Mueller's avatar
Thomas Mueller committed
2325 2326
"

2327 2328
"Other Grammar","Dollar Quoted String","
$$anythingExceptTwoDollarSigns$$
Thomas Mueller's avatar
Thomas Mueller committed
2329
","
2330 2331 2332
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
2333
","
2334
$$John's car$$
Thomas Mueller's avatar
Thomas Mueller committed
2335 2336
"

2337 2338
"Other Grammar","Expression","
andCondition [ { OR andCondition } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2339
","
2340
Value or condition.
Thomas Mueller's avatar
Thomas Mueller committed
2341
","
2342
ID=1 OR NAME='Hi'
Thomas Mueller's avatar
Thomas Mueller committed
2343 2344
"

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

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

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

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

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

"Other Grammar","Long","
2400
[ + | - ] number
Thomas Mueller's avatar
Thomas Mueller committed
2401 2402 2403 2404 2405 2406
","
Long numbers are between -9223372036854775808 and 9223372036854775807.
","
100000
"

2407 2408 2409 2410 2411 2412 2413 2414 2415
"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","
2416 2417 2418
WHEN MATCHED [ AND expression ] THEN
UPDATE SET setClauseList
    | DELETE
2419
    | {UPDATE SET setClauseList [ WHERE expression ] DELETE [ WHERE expression ]}
2420 2421 2422 2423
","
WHEN MATCHED clause for MERGE USING command.

If both UPDATE and DELETE are specified, DELETE can delete only rows that were updated,
2424
WHERE condition in DELETE clause can be used to specify which updated rows should be deleted.
2425 2426 2427 2428 2429 2430 2431
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","
2432
WHEN NOT MATCHED [ AND expression ] THEN INSERT insertColumnsAndSource
2433 2434 2435 2436 2437 2438
","
WHEN NOT MATCHED clause for MERGE USING command.
","
WHEN NOT MATCHED THEN INSERT (ID, NAME) VALUES (S.ID, S.NAME)
"

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

2447 2448
"Other Grammar","Null","
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2449
","
2450
NULL is a value without data type and means 'unknown value'.
Thomas Mueller's avatar
Thomas Mueller committed
2451
","
2452
NULL
Thomas Mueller's avatar
Thomas Mueller committed
2453 2454
"

2455 2456 2457 2458 2459 2460 2461 2462
"Other Grammar","Number","
digit [...]
","
The maximum length of the number depends on the data type used.
","
100
"

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

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

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

2493 2494
"Other Grammar","Quoted Name","
""anythingExceptDoubleQuote""
Thomas Mueller's avatar
Thomas Mueller committed
2495
","
2496 2497 2498
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
2499
","
2500
""FirstName""
Thomas Mueller's avatar
Thomas Mueller committed
2501 2502
"

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

Thomas Mueller's avatar
Thomas Mueller committed
2518 2519 2520 2521 2522 2523 2524 2525 2526 2527 2528
"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
"

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

2540 2541 2542 2543 2544 2545 2546 2547 2548 2549
"Other Grammar","Row value expression","
ROW (expression, [,...])
    | ( [ expression, expression [,...] ] )
","
A row value expression.
","
ROW (1)
(1, 2)
"

2550
"Other Grammar","Select Expression","
2551
wildcardExpression | expression [ [ AS ] columnAlias ]
Thomas Mueller's avatar
Thomas Mueller committed
2552
","
2553
An expression in a SELECT statement.
Thomas Mueller's avatar
Thomas Mueller committed
2554
","
2555
ID AS VALUE
Thomas Mueller's avatar
Thomas Mueller committed
2556 2557
"

2558 2559 2560 2561 2562 2563 2564 2565 2566 2567 2568 2569 2570
"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
"

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

2582 2583
"Other Grammar","String","
'anythingExceptSingleQuote'
Thomas Mueller's avatar
Thomas Mueller committed
2584
","
2585 2586
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
2587
","
2588
'John''s car'
Thomas Mueller's avatar
Thomas Mueller committed
2589 2590
"

2591 2592
"Other Grammar","Summand","
factor [ { { + | - } factor } [...] ]
Thomas Mueller's avatar
Thomas Mueller committed
2593
","
Thomas Mueller's avatar
Thomas Mueller committed
2594
A value or a numeric sum.
Thomas Mueller's avatar
Thomas Mueller committed
2595

Thomas Mueller's avatar
Thomas Mueller committed
2596
Please note the text concatenation operator is ""||"".
Thomas Mueller's avatar
Thomas Mueller committed
2597
","
2598
ID + 20
Thomas Mueller's avatar
Thomas Mueller committed
2599 2600
"

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

2615 2616 2617 2618 2619 2620 2621 2622 2623
"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;
"

2624 2625 2626 2627 2628 2629 2630 2631 2632 2633
"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)
"

2634 2635
"Other Grammar","Window name or specification","
windowName | windowSpecification
2636
","
2637
A window name or inline specification for a window function or aggregate.
2638

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

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

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.
2664 2665 2666
","
()
(W1 ORDER BY ID)
2667 2668
(PARTITION BY CATEGORY)
(PARTITION BY CATEGORY ORDER BY NAME, ID)
2669 2670 2671 2672
(ORDER BY Y RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES)
"

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

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
2697
BETWEEN windowFramePreceding AND CURRENT ROW.
2698 2699 2700 2701 2702 2703

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.
2704
","
2705
ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW EXCLUDE TIES
2706 2707
"

2708 2709 2710 2711 2712 2713 2714 2715 2716 2717 2718
"Other Grammar","Window frame preceding","
UNBOUNDED PRECEDING|value PRECEDING|CURRENT ROW
","
A window frame preceding clause.
If value is specified it should be non-negative value or parameter.
","
UNBOUNDED PRECEDING
1 PRECEDING
CURRENT ROW
"

2719 2720 2721
"Other Grammar","Window frame bound","
UNBOUNDED PRECEDING|value PRECEDING|CURRENT ROW
    |value FOLLOWING|UNBOUNDED FOLLOWING
2722
","
2723
A window frame bound clause.
2724 2725
If value is specified it should be non-negative value or parameter.
","
2726
UNBOUNDED PRECEDING
2727 2728 2729 2730 2731
UNBOUNDED FOLLOWING
1 FOLLOWING
CURRENT ROW
"

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

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

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

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

2784 2785 2786 2787 2788 2789 2790 2791
"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'
"

2792 2793 2794 2795 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
"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.
","
2853
INTERVAL '10 11' DAY TO HOUR
2854 2855 2856 2857 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
"

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

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

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

2921
Mapped to ""java.lang.Integer"".
Thomas Mueller's avatar
Thomas Mueller committed
2922 2923 2924 2925 2926 2927 2928 2929 2930
","
INT
"

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

2931
Mapped to ""java.lang.Boolean"".
Thomas Mueller's avatar
Thomas Mueller committed
2932 2933 2934 2935 2936 2937 2938 2939 2940
","
BOOLEAN
"

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

2941
Mapped to ""java.lang.Byte"".
Thomas Mueller's avatar
Thomas Mueller committed
2942 2943 2944 2945 2946 2947 2948 2949 2950
","
TINYINT
"

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

2951
Mapped to ""java.lang.Short"".
Thomas Mueller's avatar
Thomas Mueller committed
2952 2953 2954 2955 2956 2957 2958 2959 2960
","
SMALLINT
"

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

2961
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2962 2963 2964 2965 2966 2967 2968 2969 2970 2971 2972
","
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.

2973
Mapped to ""java.lang.Long"".
Thomas Mueller's avatar
Thomas Mueller committed
2974 2975 2976 2977 2978
","
IDENTITY
"

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

2984
Mapped to ""java.math.BigDecimal"".
Thomas Mueller's avatar
Thomas Mueller committed
2985 2986 2987 2988 2989
","
DECIMAL(20, 2)
"

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

2996
Mapped to ""java.lang.Double"".
Thomas Mueller's avatar
Thomas Mueller committed
2997 2998 2999 3000 3001
","
DOUBLE
"

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

3008
Mapped to ""java.lang.Float"".
Thomas Mueller's avatar
Thomas Mueller committed
3009 3010 3011 3012 3013
","
REAL
"

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

3019
Mapped to ""java.sql.Time"". When converted to a ""java.sql.Date"", the date is set to ""1970-01-01"".
3020
""java.time.LocalTime"" is also supported on Java 8 and later versions.
3021
Use ""java.time.LocalTime"" or ""String"" instead of ""java.sql.Time"" when non-zero precision is needed.
3022 3023
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
3024 3025
","
TIME
3026
TIME(9)
Thomas Mueller's avatar
Thomas Mueller committed
3027 3028 3029 3030 3031
"

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

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

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

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

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

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

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

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

"Data Types","OTHER Type","
OTHER
","
Thomas Mueller's avatar
Thomas Mueller committed
3097 3098 3099 3100 3101
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
3102

3103
Mapped to ""java.lang.Object"" (or any subclass).
Thomas Mueller's avatar
Thomas Mueller committed
3104 3105 3106 3107 3108
","
OTHER
"

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

3121
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3122 3123 3124 3125 3126
","
VARCHAR(255)
"

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

3138
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3139 3140 3141 3142 3143
","
VARCHAR_IGNORECASE
"

"Data Types","CHAR Type","
3144
{ CHAR | CHARACTER | NCHAR } [ ( precisionInt ) ]
Thomas Mueller's avatar
Thomas Mueller committed
3145
","
Thomas Mueller's avatar
Thomas Mueller committed
3146 3147 3148
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
3149

Thomas Mueller's avatar
Thomas Mueller committed
3150 3151
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
3152

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

3156
Mapped to ""java.lang.String"".
Thomas Mueller's avatar
Thomas Mueller committed
3157 3158 3159 3160 3161
","
CHAR(10)
"

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

3171
Mapped to ""java.sql.Blob"" (""java.io.InputStream"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3172 3173
","
BLOB
3174
BLOB(10K)
Thomas Mueller's avatar
Thomas Mueller committed
3175 3176 3177
"

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

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.

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

3194
Mapped to ""java.sql.Clob"" (""java.io.Reader"" is also supported).
Thomas Mueller's avatar
Thomas Mueller committed
3195 3196
","
CLOB
3197
CLOB(10K)
Thomas Mueller's avatar
Thomas Mueller committed
3198 3199 3200 3201 3202
"

"Data Types","UUID Type","
UUID
","
Thomas Mueller's avatar
Thomas Mueller committed
3203 3204 3205 3206
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
3207

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

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

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
3226 3227 3228 3229
","
ARRAY
"

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

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

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

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

3326
"Interval Data Types","INTERVAL DAY Type","
3327 3328 3329 3330 3331 3332 3333 3334 3335 3336 3337
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
"

3338
"Interval Data Types","INTERVAL HOUR Type","
3339 3340 3341 3342 3343 3344 3345 3346 3347 3348 3349
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
"

3350
"Interval Data Types","INTERVAL MINUTE Type","
3351 3352 3353 3354 3355 3356 3357 3358 3359 3360 3361
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
"

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

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

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

Mapped to ""org.h2.api.Interval"".
3382
""java.time.Period"" is also supported on Java 8 and later versions.
3383 3384 3385 3386
","
INTERVAL YEAR TO MONTH
"

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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
3518
","
3519
ANY(NAME LIKE 'W%')
3520
A = (ANY((SELECT B FROM T)))
Thomas Mueller's avatar
Thomas Mueller committed
3521 3522 3523
"

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

"Functions (Aggregate)","GROUP_CONCAT","
3536
GROUP_CONCAT ( [ DISTINCT|ALL ] string
3537
[ ORDER BY { expression [ ASC | DESC ] } [,...] ]
3538
[ SEPARATOR expression ] )
3539
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3540
","
3541 3542 3543 3544 3545
Concatenates strings with a separator.
The default separator is a ',' (without space).
This method returns a string.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
Thomas Mueller's avatar
Thomas Mueller committed
3546 3547 3548 3549
","
GROUP_CONCAT(NAME ORDER BY ID SEPARATOR ', ')
"

3550
"Functions (Aggregate)","ARRAY_AGG","
3551
ARRAY_AGG ( [ DISTINCT|ALL ] string
3552
[ ORDER BY { expression [ ASC | DESC ] } [,...] ] )
3553
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3554 3555 3556 3557 3558 3559 3560 3561 3562
","
Aggregate the value into an array.
This method returns an array.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
","
ARRAY_AGG(NAME ORDER BY ID)
"

Thomas Mueller's avatar
Thomas Mueller committed
3563
"Functions (Aggregate)","MAX","
3564
MAX(value)
3565
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3566
","
3567 3568 3569 3570
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
3571 3572 3573 3574 3575
","
MAX(NAME)
"

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

"Functions (Aggregate)","SUM","
3588
SUM( [ DISTINCT|ALL ] { numeric } )
3589
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3590
","
3591 3592 3593
The sum of all values.
If no rows are selected, the result is NULL.
Aggregates are only allowed in select statements.
3594
The data type of the returned value depends on the parameter data type like this:
Thomas Mueller's avatar
Thomas Mueller committed
3595
""BOOLEAN, TINYINT, SMALLINT, INT -> BIGINT, BIGINT -> DECIMAL, REAL -> DOUBLE""
Thomas Mueller's avatar
Thomas Mueller committed
3596 3597 3598 3599 3600
","
SUM(X)
"

"Functions (Aggregate)","SELECTIVITY","
3601
SELECTIVITY(value)
3602
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3603
","
3604 3605 3606 3607 3608
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
3609 3610 3611 3612 3613
","
SELECT SELECTIVITY(FIRSTNAME), SELECTIVITY(NAME) FROM TEST WHERE ROWNUM()<20000
"

"Functions (Aggregate)","STDDEV_POP","
3614
STDDEV_POP( [ DISTINCT|ALL ] numeric )
3615
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3616
","
3617 3618 3619
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
3620 3621 3622 3623 3624 3625
Aggregates are only allowed in select statements.
","
STDDEV_POP(X)
"

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

"Functions (Aggregate)","VAR_POP","
3638
VAR_POP( [ DISTINCT|ALL ] numeric )
3639
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
Thomas Mueller's avatar
Thomas Mueller committed
3640
","
3641 3642 3643 3644
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
3645 3646 3647 3648 3649
","
VAR_POP(X)
"

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

3661
"Functions (Aggregate)","MEDIAN","
3662
MEDIAN( [ DISTINCT|ALL ] value )
3663
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3664 3665 3666
","
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.
3667
Interpolation is only supported for numeric, date-time, and interval data types.
3668 3669 3670 3671 3672 3673 3674
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)
"

3675
"Functions (Aggregate)","MODE","
3676 3677
{ MODE( value ) [ ORDER BY expression [ ASC | DESC ] ] }
    | { MODE() WITHIN GROUP(ORDER BY expression [ ASC | DESC ]) }
3678
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3679 3680 3681
","
Returns the value that occurs with the greatest frequency.
If there are multiple values with the same frequency only one value will be returned.
3682 3683 3684 3685 3686
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.
3687 3688 3689 3690 3691
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)
3692
MODE(X ORDER BY X)
3693
MODE() WITHIN GROUP(ORDER BY X)
3694 3695
"

3696
"Functions (Aggregate)","ENVELOPE","
3697
ENVELOPE( value )
3698
[FILTER (WHERE expression)] [OVER windowNameOrSpecification]
3699 3700 3701 3702 3703 3704 3705
","
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.
","
3706
ENVELOPE(X)
3707 3708
"

Thomas Mueller's avatar
Thomas Mueller committed
3709
"Functions (Numeric)","ABS","
3710
ABS(numeric|interval)
Thomas Mueller's avatar
Thomas Mueller committed
3711
","
3712
Returns the absolute value of a specified value.
3713
The returned value is of the same data type as the parameter.
3714 3715 3716 3717 3718 3719 3720

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
3721
","
3722 3723
ABS(VALUE)
ABS(CAST(VALUE AS BIGINT))
Thomas Mueller's avatar
Thomas Mueller committed
3724 3725 3726
"

"Functions (Numeric)","ACOS","
Thomas Mueller's avatar
Thomas Mueller committed
3727
ACOS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3728
","
Thomas Mueller's avatar
Thomas Mueller committed
3729 3730
Calculate the arc cosine.
See also Java ""Math.acos"".
3731
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3732 3733 3734 3735 3736
","
ACOS(D)
"

"Functions (Numeric)","ASIN","
Thomas Mueller's avatar
Thomas Mueller committed
3737
ASIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3738
","
Thomas Mueller's avatar
Thomas Mueller committed
3739 3740
Calculate the arc sine.
See also Java ""Math.asin"".
3741
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3742 3743 3744 3745 3746
","
ASIN(D)
"

"Functions (Numeric)","ATAN","
Thomas Mueller's avatar
Thomas Mueller committed
3747
ATAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3748
","
Thomas Mueller's avatar
Thomas Mueller committed
3749 3750
Calculate the arc tangent.
See also Java ""Math.atan"".
3751
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3752 3753 3754 3755 3756
","
ATAN(D)
"

"Functions (Numeric)","COS","
Thomas Mueller's avatar
Thomas Mueller committed
3757
COS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3758
","
Thomas Mueller's avatar
Thomas Mueller committed
3759 3760
Calculate the trigonometric cosine.
See also Java ""Math.cos"".
3761
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3762 3763 3764 3765
","
COS(ANGLE)
"

3766
"Functions (Numeric)","COSH","
Thomas Mueller's avatar
Thomas Mueller committed
3767
COSH(numeric)
3768 3769 3770 3771 3772 3773 3774 3775
","
Calculate the hyperbolic cosine.
See also Java ""Math.cosh"".
This method returns a double.
","
COSH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3776
"Functions (Numeric)","COT","
Thomas Mueller's avatar
Thomas Mueller committed
3777
COT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3778
","
Thomas Mueller's avatar
Thomas Mueller committed
3779
Calculate the trigonometric cotangent (""1/TAN(ANGLE)"").
3780
See also Java ""Math.*"" functions.
3781
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3782 3783 3784 3785 3786
","
COT(ANGLE)
"

"Functions (Numeric)","SIN","
Thomas Mueller's avatar
Thomas Mueller committed
3787
SIN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3788
","
Thomas Mueller's avatar
Thomas Mueller committed
3789 3790
Calculate the trigonometric sine.
See also Java ""Math.sin"".
3791
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3792 3793 3794 3795
","
SIN(ANGLE)
"

3796
"Functions (Numeric)","SINH","
Thomas Mueller's avatar
Thomas Mueller committed
3797
SINH(numeric)
3798 3799 3800 3801 3802 3803 3804 3805
","
Calculate the hyperbolic sine.
See also Java ""Math.sinh"".
This method returns a double.
","
SINH(ANGLE)
"

Thomas Mueller's avatar
Thomas Mueller committed
3806
"Functions (Numeric)","TAN","
Thomas Mueller's avatar
Thomas Mueller committed
3807
TAN(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3808
","
Thomas Mueller's avatar
Thomas Mueller committed
3809 3810
Calculate the trigonometric tangent.
See also Java ""Math.tan"".
3811
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3812 3813 3814 3815
","
TAN(ANGLE)
"

3816
"Functions (Numeric)","TANH","
Thomas Mueller's avatar
Thomas Mueller committed
3817
TANH(numeric)
3818 3819 3820 3821 3822 3823 3824 3825
","
Calculate the hyperbolic tangent.
See also Java ""Math.tanh"".
This method returns a double.
","
TANH(X)
"

Thomas Mueller's avatar
Thomas Mueller committed
3826
"Functions (Numeric)","ATAN2","
Thomas Mueller's avatar
Thomas Mueller committed
3827
ATAN2(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3828
","
Thomas Mueller's avatar
Thomas Mueller committed
3829
Calculate the angle when converting the rectangular coordinates to polar coordinates.
3830
See also Java ""Math.atan2"".
3831
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3832 3833 3834 3835 3836
","
ATAN2(X, Y)
"

"Functions (Numeric)","BITAND","
3837
BITAND(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3838
","
3839 3840
The bitwise AND operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3841 3842 3843 3844 3845
See also Java operator &.
","
BITAND(A, B)
"

3846 3847 3848 3849 3850 3851 3852 3853 3854 3855 3856
"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
3857
"Functions (Numeric)","BITOR","
3858
BITOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3859
","
3860 3861
The bitwise OR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3862 3863 3864 3865 3866 3867
See also Java operator |.
","
BITOR(A, B)
"

"Functions (Numeric)","BITXOR","
3868
BITXOR(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3869
","
3870 3871
The bitwise XOR operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3872 3873 3874 3875 3876 3877
See also Java operator ^.
","
BITXOR(A, B)
"

"Functions (Numeric)","MOD","
3878
MOD(long, long)
Thomas Mueller's avatar
Thomas Mueller committed
3879
","
3880 3881
The modulo operation.
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
3882 3883 3884 3885 3886 3887
See also Java operator %.
","
MOD(A, B)
"

"Functions (Numeric)","CEILING","
Thomas Mueller's avatar
Thomas Mueller committed
3888
{ CEILING | CEIL } (numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3889
","
3890
See also Java ""Math.ceil"".
3891
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3892
","
3893
CEIL(A)
Thomas Mueller's avatar
Thomas Mueller committed
3894 3895 3896
"

"Functions (Numeric)","DEGREES","
Thomas Mueller's avatar
Thomas Mueller committed
3897
DEGREES(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3898
","
3899
See also Java ""Math.toDegrees"".
3900
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3901 3902 3903 3904 3905
","
DEGREES(A)
"

"Functions (Numeric)","EXP","
Thomas Mueller's avatar
Thomas Mueller committed
3906
EXP(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3907
","
3908
See also Java ""Math.exp"".
3909
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3910 3911 3912 3913 3914
","
EXP(A)
"

"Functions (Numeric)","FLOOR","
Thomas Mueller's avatar
Thomas Mueller committed
3915
FLOOR(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3916
","
3917
See also Java ""Math.floor"".
3918
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3919 3920 3921 3922
","
FLOOR(A)
"

3923 3924
"Functions (Numeric)","LN","
{LN|LOG}(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3925
","
3926
Calculates the natural (base e) logarithm as a double value.
3927
In the PostgreSQL mode, LOG(x) is base 10.
3928
See also Java ""Math.log"".
Thomas Mueller's avatar
Thomas Mueller committed
3929
","
3930
LN(A)
Thomas Mueller's avatar
Thomas Mueller committed
3931 3932 3933
"

"Functions (Numeric)","LOG10","
Thomas Mueller's avatar
Thomas Mueller committed
3934
LOG10(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3935
","
3936
Calculates the base 10 logarithm as a double value.
3937
See also Java ""Math.log10"".
Thomas Mueller's avatar
Thomas Mueller committed
3938 3939 3940 3941
","
LOG10(A)
"

3942 3943 3944 3945 3946 3947 3948 3949 3950 3951 3952 3953 3954
"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
3955
"Functions (Numeric)","RADIANS","
Thomas Mueller's avatar
Thomas Mueller committed
3956
RADIANS(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3957
","
3958
See also Java ""Math.toRadians"".
3959
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3960 3961 3962 3963 3964
","
RADIANS(A)
"

"Functions (Numeric)","SQRT","
Thomas Mueller's avatar
Thomas Mueller committed
3965
SQRT(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3966
","
3967
See also Java ""Math.sqrt"".
3968
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3969 3970 3971 3972 3973
","
SQRT(A)
"

"Functions (Numeric)","PI","
3974
PI()
Thomas Mueller's avatar
Thomas Mueller committed
3975
","
3976
See also Java ""Math.PI"".
3977
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3978 3979 3980 3981 3982
","
PI()
"

"Functions (Numeric)","POWER","
Thomas Mueller's avatar
Thomas Mueller committed
3983
POWER(numeric, numeric)
Thomas Mueller's avatar
Thomas Mueller committed
3984
","
3985
See also Java ""Math.pow"".
Thomas Mueller's avatar
Thomas Mueller committed
3986
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
3987 3988 3989 3990 3991
","
POWER(A, B)
"

"Functions (Numeric)","RAND","
3992
{ RAND | RANDOM } ( [ int ] )
Thomas Mueller's avatar
Thomas Mueller committed
3993 3994 3995
","
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
3996
This method returns a double between 0 (including) and 1 (excluding).
Thomas Mueller's avatar
Thomas Mueller committed
3997 3998 3999 4000 4001
","
RAND()
"

"Functions (Numeric)","RANDOM_UUID","
4002
{ RANDOM_UUID | UUID } ()
Thomas Mueller's avatar
Thomas Mueller committed
4003 4004
","
Returns a new UUID with 122 pseudo random bits.
Thomas Mueller's avatar
Thomas Mueller committed
4005 4006 4007 4008 4009

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
4010 4011 4012 4013 4014
","
RANDOM_UUID()
"

"Functions (Numeric)","ROUND","
4015
ROUND(numeric [, digitsInt])
Thomas Mueller's avatar
Thomas Mueller committed
4016
","
4017
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
4018
This method returns a numeric (the same type as the input).
Thomas Mueller's avatar
Thomas Mueller committed
4019 4020 4021 4022 4023
","
ROUND(VALUE, 2)
"

"Functions (Numeric)","ROUNDMAGIC","
Thomas Mueller's avatar
Thomas Mueller committed
4024
ROUNDMAGIC(numeric)
Thomas Mueller's avatar
Thomas Mueller committed
4025
","
4026 4027 4028 4029 4030 4031
This function rounds numbers in a good way, but it is slow.
It has a special handling for numbers around 0.
Only numbers smaller or equal +/-1000000000000 are supported.
The value is converted to a String internally, and then the last last 4 characters are checked.
'000x' becomes '0000' and '999x' becomes '999999', which is rounded automatically.
This method returns a double.
Thomas Mueller's avatar
Thomas Mueller committed
4032 4033 4034 4035 4036
","
ROUNDMAGIC(VALUE/3*3)
"

"Functions (Numeric)","SECURE_RAND","
4037
SECURE_RAND(int)
Thomas Mueller's avatar
Thomas Mueller committed
4038 4039
","
Generates a number of cryptographically secure random numbers.
4040
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4041 4042 4043 4044 4045
","
CALL SECURE_RAND(16)
"

"Functions (Numeric)","SIGN","
4046
SIGN(numeric|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4047
","
4048
Returns -1 if the value is smaller than 0, 0 if zero, and otherwise 1.
Thomas Mueller's avatar
Thomas Mueller committed
4049 4050 4051 4052 4053
","
SIGN(VALUE)
"

"Functions (Numeric)","ENCRYPT","
4054
ENCRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
4055
","
4056
Encrypts data using a key.
4057
The supported algorithm is AES.
4058 4059
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4060 4061 4062 4063 4064
","
CALL ENCRYPT('AES', '00', STRINGTOUTF8('Test'))
"

"Functions (Numeric)","DECRYPT","
4065
DECRYPT(algorithmString, keyBytes, dataBytes)
Thomas Mueller's avatar
Thomas Mueller committed
4066
","
4067
Decrypts data using a key.
4068
The supported algorithm is AES.
4069 4070
The block size is 16 bytes.
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4071 4072 4073 4074 4075 4076
","
CALL TRIM(CHAR(0) FROM UTF8TOSTRING(
    DECRYPT('AES', '00', '3fabb4de8f1ee2e97d7793bab2db1116')))
"

"Functions (Numeric)","HASH","
4077
HASH(algorithmString, expression [, iterationInt])
Thomas Mueller's avatar
Thomas Mueller committed
4078
","
4079 4080 4081
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
4082 4083 4084 4085 4086
","
CALL HASH('SHA256', STRINGTOUTF8('Password'), 1000)
"

"Functions (Numeric)","TRUNCATE","
4087 4088
{ TRUNC | TRUNCATE } ( { {numeric, digitsInt}
    | timestamp | timestampWithTimeZone | date | timestampString } )
Thomas Mueller's avatar
Thomas Mueller committed
4089 4090
","
Truncates to a number of digits (to the next value closer to 0).
4091
This method returns a double.
4092
When used with a timestamp, truncates a timestamp to a date (day) value.
4093 4094
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
4095 4096 4097 4098 4099
","
TRUNCATE(VALUE, 2)
"

"Functions (Numeric)","COMPRESS","
4100
COMPRESS(dataBytes [, algorithmString])
Thomas Mueller's avatar
Thomas Mueller committed
4101
","
4102 4103 4104 4105
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
4106 4107 4108 4109 4110
","
COMPRESS(STRINGTOUTF8('Test'))
"

"Functions (Numeric)","EXPAND","
4111
EXPAND(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
4112 4113
","
Expands data that was compressed using the COMPRESS function.
4114
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4115 4116 4117 4118 4119
","
UTF8TOSTRING(EXPAND(COMPRESS(STRINGTOUTF8('Test'))))
"

"Functions (Numeric)","ZERO","
4120
ZERO()
Thomas Mueller's avatar
Thomas Mueller committed
4121 4122 4123 4124 4125 4126 4127
","
Returns the value 0. This function can be used even if numeric literals are disabled.
","
ZERO()
"

"Functions (String)","ASCII","
4128
ASCII(string)
Thomas Mueller's avatar
Thomas Mueller committed
4129 4130
","
Returns the ASCII value of the first character in the string.
4131
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
4132 4133 4134 4135
","
ASCII('Hi')
"
"Functions (String)","BIT_LENGTH","
4136
BIT_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
4137
","
4138 4139 4140
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
4141 4142 4143 4144 4145
","
BIT_LENGTH(NAME)
"

"Functions (String)","LENGTH","
4146
{ LENGTH | CHAR_LENGTH | CHARACTER_LENGTH } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4147
","
4148 4149 4150
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
4151 4152 4153 4154 4155
","
LENGTH(NAME)
"

"Functions (String)","OCTET_LENGTH","
4156
OCTET_LENGTH(string)
Thomas Mueller's avatar
Thomas Mueller committed
4157
","
4158 4159 4160 4161
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
4162 4163 4164 4165 4166
","
OCTET_LENGTH(NAME)
"

"Functions (String)","CHAR","
4167
{ CHAR | CHR } ( int )
Thomas Mueller's avatar
Thomas Mueller committed
4168 4169
","
Returns the character that represents the ASCII value.
4170
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4171 4172 4173 4174 4175
","
CHAR(65)
"

"Functions (String)","CONCAT","
4176
CONCAT(string, string [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4177 4178
","
Combines strings.
Thomas Mueller's avatar
Thomas Mueller committed
4179
Unlike with the operator ""||"", NULL parameters are ignored,
Thomas Mueller's avatar
Thomas Mueller committed
4180
and do not cause the result to become NULL.
4181
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4182 4183 4184 4185
","
CONCAT(NAME, '!')
"

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

Thomas Mueller's avatar
Thomas Mueller committed
4197
"Functions (String)","DIFFERENCE","
4198
DIFFERENCE(string, string)
Thomas Mueller's avatar
Thomas Mueller committed
4199 4200
","
Returns the difference between the sounds of two strings.
4201 4202 4203 4204 4205
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
4206 4207 4208 4209 4210
","
DIFFERENCE(T1.NAME, T2.NAME)
"

"Functions (String)","HEXTORAW","
4211
HEXTORAW(string)
Thomas Mueller's avatar
Thomas Mueller committed
4212
","
4213 4214
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
4215 4216 4217 4218 4219
","
HEXTORAW(DATA)
"

"Functions (String)","RAWTOHEX","
4220
RAWTOHEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
4221
","
4222 4223 4224
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
4225 4226 4227 4228 4229
","
RAWTOHEX(DATA)
"

"Functions (String)","INSTR","
4230
INSTR(string, searchString, [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
4231
","
4232
Returns the location of a search string in a string.
4233 4234 4235
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
4236
Please note this function is case sensitive, even if the parameters are not.
Thomas Mueller's avatar
Thomas Mueller committed
4237 4238 4239 4240 4241
","
INSTR(EMAIL,'@')
"

"Functions (String)","INSERT Function","
4242
INSERT(originalString, startInt, lengthInt, addString)
Thomas Mueller's avatar
Thomas Mueller committed
4243
","
4244 4245 4246
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
4247 4248 4249 4250 4251
","
INSERT(NAME, 1, 1, ' ')
"

"Functions (String)","LOWER","
4252
{ LOWER | LCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4253 4254 4255 4256 4257 4258 4259
","
Converts a string to lowercase.
","
LOWER(NAME)
"

"Functions (String)","UPPER","
4260
{ UPPER | UCASE } ( string )
Thomas Mueller's avatar
Thomas Mueller committed
4261 4262 4263 4264 4265 4266 4267
","
Converts a string to uppercase.
","
UPPER(NAME)
"

"Functions (String)","LEFT","
4268
LEFT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4269 4270 4271 4272 4273 4274 4275
","
Returns the leftmost number of characters.
","
LEFT(NAME, 3)
"

"Functions (String)","RIGHT","
4276
RIGHT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4277 4278 4279 4280 4281 4282 4283
","
Returns the rightmost number of characters.
","
RIGHT(NAME, 3)
"

"Functions (String)","LOCATE","
4284
LOCATE(searchString, string [, startInt])
Thomas Mueller's avatar
Thomas Mueller committed
4285
","
4286 4287 4288 4289
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
4290 4291 4292 4293 4294
","
LOCATE('.', NAME)
"

"Functions (String)","POSITION","
4295
POSITION(searchString, string)
Thomas Mueller's avatar
Thomas Mueller committed
4296 4297 4298 4299 4300 4301 4302
","
Returns the location of a search string in a string. See also LOCATE.
","
POSITION('.', NAME)
"

"Functions (String)","LPAD","
4303
LPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
4304
","
4305 4306 4307
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
4308 4309 4310 4311 4312
","
LPAD(AMOUNT, 10, '*')
"

"Functions (String)","RPAD","
4313
RPAD(string, int[, paddingString])
Thomas Mueller's avatar
Thomas Mueller committed
4314
","
4315 4316 4317
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
4318 4319 4320 4321 4322
","
RPAD(TEXT, 10, '-')
"

"Functions (String)","LTRIM","
4323
LTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
4324 4325 4326 4327 4328 4329 4330
","
Removes all leading spaces from a string.
","
LTRIM(NAME)
"

"Functions (String)","RTRIM","
4331
RTRIM(string)
Thomas Mueller's avatar
Thomas Mueller committed
4332 4333 4334 4335 4336 4337 4338
","
Removes all trailing spaces from a string.
","
RTRIM(NAME)
"

"Functions (String)","TRIM","
4339
TRIM ( [ { LEADING | TRAILING | BOTH } [ string ] FROM ] string )
Thomas Mueller's avatar
Thomas Mueller committed
4340
","
4341 4342
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
4343 4344 4345 4346 4347
","
TRIM(BOTH '_' FROM NAME)
"

"Functions (String)","REGEXP_REPLACE","
4348
REGEXP_REPLACE(inputString, regexString, replacementString [, flagsString])
Thomas Mueller's avatar
Thomas Mueller committed
4349
","
4350
Replaces each substring that matches a regular expression.
4351
For details, see the Java ""String.replaceAll()"" method.
4352 4353 4354 4355 4356 4357 4358 4359 4360 4361 4362 4363 4364 4365
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
4366 4367
","
REGEXP_REPLACE('Hello    World', ' +', ' ')
4368
REGEXP_REPLACE('Hello WWWWorld', 'w+', 'W', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
4369 4370
"

4371 4372 4373 4374
"Functions (String)","REGEXP_LIKE","
REGEXP_LIKE(inputString, regexString [, flagsString])
","
Matches string to a regular expression.
4375 4376 4377 4378 4379 4380 4381 4382 4383 4384 4385 4386 4387 4388 4389
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)

4390 4391
","
REGEXP_LIKE('Hello    World', '[A-Z ]*', 'i')
Thomas Mueller's avatar
Thomas Mueller committed
4392 4393 4394
"

"Functions (String)","REPEAT","
4395
REPEAT(string, int)
Thomas Mueller's avatar
Thomas Mueller committed
4396 4397 4398 4399 4400 4401 4402
","
Returns a string repeated some number of times.
","
REPEAT(NAME || ' ', 10)
"

"Functions (String)","REPLACE","
4403
REPLACE(string, searchString [, replacementString])
Thomas Mueller's avatar
Thomas Mueller committed
4404
","
4405 4406
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.
4407
If any parameter is null, the result is null.
Thomas Mueller's avatar
Thomas Mueller committed
4408 4409 4410 4411 4412
","
REPLACE(NAME, ' ')
"

"Functions (String)","SOUNDEX","
4413
SOUNDEX(string)
Thomas Mueller's avatar
Thomas Mueller committed
4414
","
4415
Returns a four character code representing the sound of a string.
4416 4417
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
4418 4419 4420 4421 4422
","
SOUNDEX(NAME)
"

"Functions (String)","SPACE","
4423
SPACE(int)
Thomas Mueller's avatar
Thomas Mueller committed
4424 4425 4426 4427 4428 4429 4430
","
Returns a string consisting of a number of spaces.
","
SPACE(80)
"

"Functions (String)","STRINGDECODE","
4431
STRINGDECODE(string)
Thomas Mueller's avatar
Thomas Mueller committed
4432
","
4433 4434 4435
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
4436 4437 4438 4439 4440
","
CALL STRINGENCODE(STRINGDECODE('Lines 1\nLine 2'))
"

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

"Functions (String)","STRINGTOUTF8","
4451
STRINGTOUTF8(string)
Thomas Mueller's avatar
Thomas Mueller committed
4452 4453
","
Encodes a string to a byte array using the UTF8 encoding format.
4454
This method returns bytes.
Thomas Mueller's avatar
Thomas Mueller committed
4455 4456 4457 4458 4459
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","SUBSTRING","
4460
{ SUBSTRING | SUBSTR } ( string, startInt [, lengthInt ] )
Thomas Mueller's avatar
Thomas Mueller committed
4461
","
4462
Returns a substring of a string starting at a position.
4463
If the start index is negative, then the start index is relative to the end of the string.
4464
The length is optional.
4465
Also supported is: ""SUBSTRING(string [FROM start] [FOR length])"".
Thomas Mueller's avatar
Thomas Mueller committed
4466
","
4467 4468
CALL SUBSTR('[Hello]', 2, 5);
CALL SUBSTR('Hello World', -5);
Thomas Mueller's avatar
Thomas Mueller committed
4469 4470 4471
"

"Functions (String)","UTF8TOSTRING","
4472
UTF8TOSTRING(bytes)
Thomas Mueller's avatar
Thomas Mueller committed
4473 4474 4475 4476 4477 4478 4479
","
Decodes a byte array in the UTF8 format to a string.
","
CALL UTF8TOSTRING(STRINGTOUTF8('This is a test'))
"

"Functions (String)","XMLATTR","
4480
XMLATTR(nameString, valueString)
Thomas Mueller's avatar
Thomas Mueller committed
4481
","
4482
Creates an XML attribute element of the form ""name=value"".
4483 4484
The value is encoded as XML text.
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4485 4486 4487 4488 4489
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'))
"

"Functions (String)","XMLNODE","
4490
XMLNODE(elementString [, attributesString [, contentString [, indentBoolean]]])
Thomas Mueller's avatar
Thomas Mueller committed
4491 4492
","
Create an XML node element.
4493 4494 4495
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.
4496
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4497 4498 4499 4500 4501
","
CALL XMLNODE('a', XMLATTR('href', 'http://h2database.com'), 'H2')
"

"Functions (String)","XMLCOMMENT","
4502
XMLCOMMENT(commentString)
Thomas Mueller's avatar
Thomas Mueller committed
4503
","
4504
Creates an XML comment.
4505
Two dashes (""--"") are converted to ""- -"".
4506
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4507 4508 4509 4510 4511
","
CALL XMLCOMMENT('Test')
"

"Functions (String)","XMLCDATA","
4512
XMLCDATA(valueString)
Thomas Mueller's avatar
Thomas Mueller committed
4513
","
4514
Creates an XML CDATA element.
4515
If the value contains ""]]>"", an XML text element is created instead.
4516
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4517 4518 4519 4520 4521
","
CALL XMLCDATA('data')
"

"Functions (String)","XMLSTARTDOC","
4522
XMLSTARTDOC()
Thomas Mueller's avatar
Thomas Mueller committed
4523
","
Thomas Mueller's avatar
Thomas Mueller committed
4524
Returns the XML declaration.
4525
The result is always ""<?xml version=""1.0""?>"".
Thomas Mueller's avatar
Thomas Mueller committed
4526 4527 4528 4529 4530
","
CALL XMLSTARTDOC()
"

"Functions (String)","XMLTEXT","
4531
XMLTEXT(valueString [, escapeNewlineBoolean])
Thomas Mueller's avatar
Thomas Mueller committed
4532 4533
","
Creates an XML text element.
Thomas Mueller's avatar
Thomas Mueller committed
4534
If enabled, newline and linefeed is converted to an XML entity (&#).
4535
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4536 4537 4538 4539
","
CALL XMLTEXT('test')
"

4540
"Functions (String)","TO_CHAR","
4541
TO_CHAR(value [, formatString[, nlsParamString]])
4542 4543 4544 4545 4546 4547
","
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')
"

4548
"Functions (String)","TRANSLATE","
4549
TRANSLATE(value, searchString, replacementString)
4550 4551 4552 4553 4554 4555
","
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
4556
"Functions (Time and Date)","CURRENT_DATE","
4557
{ CURRENT_DATE | CURDATE() | SYSDATE | TODAY }
Thomas Mueller's avatar
Thomas Mueller committed
4558 4559
","
Returns the current date.
4560 4561
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
4562
","
4563
CURRENT_DATE
Thomas Mueller's avatar
Thomas Mueller committed
4564 4565 4566
"

"Functions (Time and Date)","CURRENT_TIME","
4567
CURRENT_TIME [ (int) ]
Thomas Mueller's avatar
Thomas Mueller committed
4568 4569
","
Returns the current time.
4570
The returned value does not have time zone information, because TIME WITH TIME ZONE data type is not supported in H2.
4571 4572 4573 4574
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.
4575 4576
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
4577
","
4578
CURRENT_TIME
4579
CURRENT_TIME(9)
Thomas Mueller's avatar
Thomas Mueller committed
4580 4581 4582
"

"Functions (Time and Date)","CURRENT_TIMESTAMP","
4583
CURRENT_TIMESTAMP [ (int) ]
4584 4585
","
Returns the current timestamp with time zone.
4586
Time zone offset is set to a current time zone offset.
4587
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
4588 4589 4590
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.
4591 4592
This method always returns the same value within a transaction (default)
or within a command depending on database mode.
4593
","
4594 4595
CURRENT_TIMESTAMP
CURRENT_TIMESTAMP(9)
4596 4597
"

4598 4599 4600 4601 4602 4603 4604 4605 4606 4607 4608 4609 4610 4611 4612
"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)
"

4613
"Functions (Time and Date)","LOCALTIMESTAMP","
4614
{ LOCALTIMESTAMP [ (int) ] | NOW( [ int ] ) }
Thomas Mueller's avatar
Thomas Mueller committed
4615
","
4616
Returns the current timestamp without time zone.
4617
If fractional seconds precision is specified it should be from 0 to 9, 6 is default.
4618 4619 4620
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.
4621 4622
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
4623
","
4624 4625
LOCALTIMESTAMP
LOCALTIMESTAMP(9)
Thomas Mueller's avatar
Thomas Mueller committed
4626 4627 4628
"

"Functions (Time and Date)","DATEADD","
4629
{ DATEADD| TIMESTAMPADD } (datetimeField, addIntLong, dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4630
","
4631
Adds units to a date-time value. The datetimeField indicates the unit.
4632
Use negative values to subtract units.
4633
addIntLong may be a long value when manipulating milliseconds,
4634
microseconds, or nanoseconds otherwise its range is restricted to int.
4635
This method returns a value with the same type as specified value if unit is compatible with this value.
4636 4637 4638
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
4639 4640 4641 4642 4643
","
DATEADD('MONTH', 1, DATE '2001-01-31')
"

"Functions (Time and Date)","DATEDIFF","
4644
{ DATEDIFF | TIMESTAMPDIFF } (datetimeField, aDateAndTime, bDateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4645
","
4646
Returns the the number of crossed unit boundaries between two date/time values.
4647
This method returns a long.
4648
The datetimeField indicates the unit.
4649 4650
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
4651
","
4652
DATEDIFF(YEAR, T1.CREATED, T2.CREATED)
Thomas Mueller's avatar
Thomas Mueller committed
4653 4654 4655
"

"Functions (Time and Date)","DAYNAME","
4656
DAYNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4657 4658 4659 4660 4661 4662 4663
","
Returns the name of the day (in English).
","
DAYNAME(CREATED)
"

"Functions (Time and Date)","DAY_OF_MONTH","
4664
DAY_OF_MONTH(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4665 4666 4667 4668 4669 4670 4671
","
Returns the day of the month (1-31).
","
DAY_OF_MONTH(CREATED)
"

"Functions (Time and Date)","DAY_OF_WEEK","
4672
DAY_OF_WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4673 4674 4675 4676 4677 4678
","
Returns the day of the week (1 means Sunday).
","
DAY_OF_WEEK(CREATED)
"

4679 4680 4681 4682 4683 4684 4685 4686
"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
4687
"Functions (Time and Date)","DAY_OF_YEAR","
4688
DAY_OF_YEAR(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4689 4690 4691 4692 4693 4694 4695
","
Returns the day of the year (1-366).
","
DAY_OF_YEAR(CREATED)
"

"Functions (Time and Date)","EXTRACT","
4696
EXTRACT ( datetimeField FROM { dateAndTime | interval })
Thomas Mueller's avatar
Thomas Mueller committed
4697
","
4698
Returns a value of the specific time unit from a date/time value.
4699 4700
This method returns a numeric value with EPOCH field and
an int for all other fields.
Thomas Mueller's avatar
Thomas Mueller committed
4701 4702 4703 4704 4705
","
EXTRACT(SECOND FROM CURRENT_TIMESTAMP)
"

"Functions (Time and Date)","FORMATDATETIME","
4706
FORMATDATETIME ( dateAndTime, formatString
4707
[ , localeString [ , timeZoneString ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4708
","
4709 4710 4711
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.
4712
For details of the format, see ""java.text.SimpleDateFormat"".
4713 4714
timeZoneString may be specified if dateAndTime is a DATE, TIME or TIMESTAMP.
timeZoneString is ignored if dateAndTime is TIMESTAMP WITH TIME ZONE.
4715
This method returns a string.
Thomas Mueller's avatar
Thomas Mueller committed
4716 4717 4718 4719 4720 4721
","
CALL FORMATDATETIME(TIMESTAMP '2001-02-03 04:05:06',
    'EEE, d MMM yyyy HH:mm:ss z', 'en', 'GMT')
"

"Functions (Time and Date)","HOUR","
4722
HOUR(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4723
","
4724
Returns the hour (0-23) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4725 4726 4727 4728 4729
","
HOUR(CREATED)
"

"Functions (Time and Date)","MINUTE","
4730
MINUTE(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4731
","
4732
Returns the minute (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4733 4734 4735 4736 4737
","
MINUTE(CREATED)
"

"Functions (Time and Date)","MONTH","
4738
MONTH(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4739
","
4740
Returns the month (1-12) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4741 4742 4743 4744 4745
","
MONTH(CREATED)
"

"Functions (Time and Date)","MONTHNAME","
4746
MONTHNAME(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4747 4748 4749 4750 4751 4752 4753
","
Returns the name of the month (in English).
","
MONTHNAME(CREATED)
"

"Functions (Time and Date)","PARSEDATETIME","
4754
PARSEDATETIME(string, formatString
4755
[, localeString [, timeZoneString]])
Thomas Mueller's avatar
Thomas Mueller committed
4756
","
4757 4758 4759
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.
4760
For details of the format, see ""java.text.SimpleDateFormat"".
Thomas Mueller's avatar
Thomas Mueller committed
4761 4762 4763 4764 4765 4766
","
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","
4767
QUARTER(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4768
","
4769
Returns the quarter (1-4) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4770 4771 4772 4773 4774
","
QUARTER(CREATED)
"

"Functions (Time and Date)","SECOND","
4775
SECOND(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4776
","
4777
Returns the second (0-59) from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4778
","
4779
SECOND(CREATED|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4780 4781 4782
"

"Functions (Time and Date)","WEEK","
4783
WEEK(dateAndTime)
Thomas Mueller's avatar
Thomas Mueller committed
4784
","
4785
Returns the week (1-53) from a date/time value.
4786
This method uses the current system locale.
Thomas Mueller's avatar
Thomas Mueller committed
4787 4788 4789 4790
","
WEEK(CREATED)
"

4791
"Functions (Time and Date)","ISO_WEEK","
4792
ISO_WEEK(dateAndTime)
4793
","
4794
Returns the ISO week (1-53) from a date/time value.
4795
This function uses the ISO definition when
4796 4797 4798 4799 4800 4801
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
4802
"Functions (Time and Date)","YEAR","
4803
YEAR(dateAndTime|interval)
Thomas Mueller's avatar
Thomas Mueller committed
4804
","
4805
Returns the year from a date/time value.
Thomas Mueller's avatar
Thomas Mueller committed
4806 4807 4808 4809
","
YEAR(CREATED)
"

4810
"Functions (Time and Date)","ISO_YEAR","
4811
ISO_YEAR(dateAndTime)
4812
","
4813
Returns the ISO week year from a date/time value.
4814 4815 4816 4817
","
ISO_YEAR(CREATED)
"

Thomas Mueller's avatar
Thomas Mueller committed
4818
"Functions (System)","ARRAY_GET","
4819
ARRAY_GET(arrayExpression, indexExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4820
","
4821
Returns element at the specified 1-based index from an array.
4822
Returns NULL if there is no such element or array is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
4823
","
4824
CALL ARRAY_GET(ARRAY['Hello', 'World'], 2)
Thomas Mueller's avatar
Thomas Mueller committed
4825 4826 4827
"

"Functions (System)","ARRAY_LENGTH","
Thomas Mueller's avatar
Thomas Mueller committed
4828
ARRAY_LENGTH(arrayExpression)
Thomas Mueller's avatar
Thomas Mueller committed
4829 4830
","
Returns the length of an array.
4831
Returns NULL if the specified array is NULL.
Thomas Mueller's avatar
Thomas Mueller committed
4832
","
4833
CALL ARRAY_LENGTH(ARRAY['Hello', 'World'])
Thomas Mueller's avatar
Thomas Mueller committed
4834 4835
"

4836 4837 4838
"Functions (System)","ARRAY_CONTAINS","
ARRAY_CONTAINS(arrayExpression, value)
","
4839 4840
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.
4841
","
4842
CALL ARRAY_CONTAINS(ARRAY['Hello', 'World'], 'Hello')
4843 4844
"

Thomas Mueller's avatar
Thomas Mueller committed
4845
"Functions (System)","AUTOCOMMIT","
4846
AUTOCOMMIT()
Thomas Mueller's avatar
Thomas Mueller committed
4847 4848 4849 4850 4851 4852 4853
","
Returns true if auto commit is switched on for this session.
","
AUTOCOMMIT()
"

"Functions (System)","CANCEL_SESSION","
4854
CANCEL_SESSION(sessionInt)
Thomas Mueller's avatar
Thomas Mueller committed
4855
","
4856 4857 4858
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
4859 4860

Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4861 4862 4863 4864 4865
","
CANCEL_SESSION(3)
"

"Functions (System)","CASEWHEN Function","
4866
CASEWHEN(boolean, aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
4867 4868
","
Returns 'a' if the boolean expression is true, otherwise 'b'.
4869
Returns the same data type as the parameter.
Thomas Mueller's avatar
Thomas Mueller committed
4870 4871 4872 4873 4874
","
CASEWHEN(ID=1, 'A', 'B')
"

"Functions (System)","CAST","
4875
CAST(value AS dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4876
","
4877 4878 4879 4880 4881 4882 4883 4884
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.
4885
Note that some data types may need explicitly specified precision to avoid overflow or rounding.
4886 4887 4888 4889
","
CAST(NAME AS INT);
CAST(65535 AS BINARY);
CAST(CAST('FFFF' AS BINARY) AS INT);
4890
CAST(TIMESTAMP '2010-01-01 10:40:00.123456' AS TIME(6))
Thomas Mueller's avatar
Thomas Mueller committed
4891 4892 4893
"

"Functions (System)","COALESCE","
4894
{ COALESCE | NVL } (aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
4895 4896 4897 4898 4899 4900 4901
","
Returns the first value that is not null.
","
COALESCE(A, B, C)
"

"Functions (System)","CONVERT","
4902
CONVERT(value, dataType)
Thomas Mueller's avatar
Thomas Mueller committed
4903 4904 4905 4906 4907 4908 4909
","
Converts a value to another data type.
","
CONVERT(NAME, INT)
"

"Functions (System)","CURRVAL","
4910
CURRVAL( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
4911
","
4912 4913 4914 4915 4916
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
4917 4918 4919 4920 4921
","
CURRVAL('TEST_SEQ')
"

"Functions (System)","CSVREAD","
4922
CSVREAD(fileNameString [, columnsString [, csvOptions ] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4923
","
4924 4925
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
4926 4927

If the column names are specified (a list of column names separated with the
4928
fieldSeparator), those are used, otherwise (or if they are set to NULL) the first line of
4929 4930 4931 4932 4933
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
4934 4935 4936 4937 4938

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.

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

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

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

Thomas Mueller's avatar
Thomas Mueller committed
4948 4949 4950
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
4951 4952 4953 4954
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
4955 4956 4957 4958
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
4959
SELECT ""Last Name"" FROM CSVREAD('address.csv');
4960
SELECT ""Last Name"" FROM CSVREAD('classpath:/org/acme/data/address.csv');
Thomas Mueller's avatar
Thomas Mueller committed
4961 4962 4963
"

"Functions (System)","CSVWRITE","
4964
CSVWRITE ( fileNameString, queryString [, csvOptions [, lineSepString] ] )
Thomas Mueller's avatar
Thomas Mueller committed
4965
","
4966
Writes a CSV (comma separated values). The file is overwritten if it exists.
Thomas Mueller's avatar
Thomas Mueller committed
4967
If only a file name is specified, it will be written to the current working directory.
4968
For each parameter, NULL means the default value should be used.
Thomas Mueller's avatar
Thomas Mueller committed
4969
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
4970 4971 4972 4973 4974

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

Thomas Mueller's avatar
Thomas Mueller committed
4977 4978
The returned value is the number or rows written.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
4979
","
Thomas Mueller's avatar
Thomas Mueller committed
4980 4981 4982 4983
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
4984 4985 4986
"

"Functions (System)","DATABASE","
4987
DATABASE()
Thomas Mueller's avatar
Thomas Mueller committed
4988 4989 4990 4991 4992 4993 4994
","
Returns the name of the database.
","
CALL DATABASE();
"

"Functions (System)","DATABASE_PATH","
4995
DATABASE_PATH()
Thomas Mueller's avatar
Thomas Mueller committed
4996
","
Thomas Mueller's avatar
Thomas Mueller committed
4997 4998
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
4999 5000 5001 5002
","
CALL DATABASE_PATH();
"

5003
"Functions (System)","DECODE","
Thomas Mueller's avatar
Thomas Mueller committed
5004
DECODE(value, whenValue, thenValue [,...])
5005 5006 5007 5008 5009 5010 5011 5012
","
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');
"

5013
"Functions (System)","DISK_SPACE_USED","
Thomas Mueller's avatar
Thomas Mueller committed
5014
DISK_SPACE_USED(tableNameString)
5015 5016 5017 5018 5019 5020 5021 5022
","
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');
"

5023
"Functions (System)","SIGNAL","
5024
SIGNAL(sqlStateString, messageString)
5025 5026 5027 5028 5029 5030
","
Throw an SQLException with the passed SQLState and reason.
","
CALL SIGNAL('23505', 'Duplicate user ID: ' || user_id);
"

5031 5032 5033 5034 5035 5036 5037 5038 5039 5040 5041 5042 5043 5044 5045 5046 5047
"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
5048
"Functions (System)","FILE_READ","
5049
FILE_READ(fileNameString [,encodingString])
Thomas Mueller's avatar
Thomas Mueller committed
5050 5051 5052 5053
","
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
5054
default character set for this system.
5055 5056 5057 5058

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

Thomas Mueller's avatar
Thomas Mueller committed
5059
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5060 5061 5062 5063 5064
","
SELECT LENGTH(FILE_READ('~/.h2.server.properties')) LEN;
SELECT FILE_READ('http://localhost:8182/stylesheet.css', NULL) CSS;
"

5065
"Functions (System)","FILE_WRITE","
5066
FILE_WRITE(blobValue, fileNameString)
5067 5068 5069 5070 5071 5072 5073 5074
","
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
5075
"Functions (System)","GREATEST","
5076
GREATEST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
5077 5078 5079 5080 5081 5082 5083
","
Returns the largest value that is not NULL, or NULL if all values are NULL.
","
CALL GREATEST(1, 2, 3);
"

"Functions (System)","IDENTITY","
5084
IDENTITY()
Thomas Mueller's avatar
Thomas Mueller committed
5085 5086
","
Returns the last inserted identity value for this session.
5087
This value changes whenever a new sequence number was generated,
5088
even within a trigger or Java function. See also SCOPE_IDENTITY.
5089
This method returns a long.
Thomas Mueller's avatar
Thomas Mueller committed
5090 5091 5092 5093 5094
","
CALL IDENTITY();
"

"Functions (System)","IFNULL","
5095
IFNULL(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
5096 5097 5098 5099 5100 5101 5102
","
Returns the value of 'a' if it is not null, otherwise 'b'.
","
CALL IFNULL(NULL, '');
"

"Functions (System)","LEAST","
5103
LEAST(aValue, bValue [,...])
Thomas Mueller's avatar
Thomas Mueller committed
5104 5105 5106 5107 5108 5109 5110
","
Returns the smallest value that is not NULL, or NULL if all values are NULL.
","
CALL LEAST(1, 2, 3);
"

"Functions (System)","LOCK_MODE","
5111
LOCK_MODE()
Thomas Mueller's avatar
Thomas Mueller committed
5112 5113
","
Returns the current lock mode. See SET LOCK_MODE.
5114
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5115 5116 5117 5118 5119
","
CALL LOCK_MODE();
"

"Functions (System)","LOCK_TIMEOUT","
5120
LOCK_TIMEOUT()
Thomas Mueller's avatar
Thomas Mueller committed
5121 5122 5123 5124 5125 5126 5127 5128
","
Returns the lock timeout of the current session (in milliseconds).
","
LOCK_TIMEOUT()
"

"Functions (System)","LINK_SCHEMA","
LINK_SCHEMA(targetSchemaString, driverString, urlString,
5129
userString, passwordString, sourceSchemaString)
Thomas Mueller's avatar
Thomas Mueller committed
5130
","
5131 5132 5133 5134 5135
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
5136
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5137 5138 5139 5140 5141
","
CALL LINK_SCHEMA('TEST2', '', 'jdbc:h2:test2', 'sa', 'sa', 'PUBLIC');
"

"Functions (System)","MEMORY_FREE","
5142
MEMORY_FREE()
Thomas Mueller's avatar
Thomas Mueller committed
5143
","
Thomas Mueller's avatar
Thomas Mueller committed
5144
Returns the free memory in KB (where 1024 bytes is a KB).
5145
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5146 5147
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5148 5149 5150 5151 5152
","
MEMORY_FREE()
"

"Functions (System)","MEMORY_USED","
5153
MEMORY_USED()
Thomas Mueller's avatar
Thomas Mueller committed
5154
","
Thomas Mueller's avatar
Thomas Mueller committed
5155
Returns the used memory in KB (where 1024 bytes is a KB).
5156
This method returns an int.
Thomas Mueller's avatar
Thomas Mueller committed
5157 5158
The garbage is run before returning the value.
Admin rights are required to execute this command.
Thomas Mueller's avatar
Thomas Mueller committed
5159 5160 5161 5162 5163
","
MEMORY_USED()
"

"Functions (System)","NEXTVAL","
5164
NEXTVAL ( [ schemaName, ] sequenceString )
Thomas Mueller's avatar
Thomas Mueller committed
5165
","
5166 5167 5168 5169
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
5170 5171 5172 5173 5174
","
NEXTVAL('TEST_SEQ')
"

"Functions (System)","NULLIF","
5175
NULLIF(aValue, bValue)
Thomas Mueller's avatar
Thomas Mueller committed
5176 5177 5178 5179 5180 5181
","
Returns NULL if 'a' is equals to 'b', otherwise 'a'.
","
NULLIF(A, B)
"

5182 5183 5184 5185
"Functions (System)","NVL2","
NVL2(testValue, aValue, bValue)
","
If the test value is null, then 'b' is returned. Otherwise, 'a' is returned.
5186
The data type of the returned value is the data type of 'a' if this is a text type.
5187 5188 5189 5190
","
NVL2(X, 'not null', 'null')
"

Thomas Mueller's avatar
Thomas Mueller committed
5191
"Functions (System)","READONLY","
5192
READONLY()
Thomas Mueller's avatar
Thomas Mueller committed
5193 5194 5195 5196 5197 5198 5199
","
Returns true if the database is read-only.
","
READONLY()
"

"Functions (System)","ROWNUM","
5200
ROWNUM()
Thomas Mueller's avatar
Thomas Mueller committed
5201
","
5202
Returns the number of the current row.
5203
This method returns a long value.
5204
It is supported for SELECT statements, as well as for DELETE and UPDATE.
5205
The first row has the row number 1, and is calculated before ordering and grouping the result set,
5206
but after evaluating index conditions (even when the index conditions are specified in an outer query).
5207
Use the ROW_NUMBER() OVER () function to get row numbers after grouping or in specified order.
Thomas Mueller's avatar
Thomas Mueller committed
5208
","
5209 5210
SELECT ROWNUM(), * FROM TEST;
SELECT ROWNUM(), * FROM (SELECT * FROM TEST ORDER BY NAME);
Thomas Mueller's avatar
Thomas Mueller committed
5211
SELECT ID FROM (SELECT T.*, ROWNUM AS R FROM TEST T) WHERE R BETWEEN 2 AND 3;
Thomas Mueller's avatar
Thomas Mueller committed
5212 5213 5214
"

"Functions (System)","SCHEMA","
5215
SCHEMA()
Thomas Mueller's avatar
Thomas Mueller committed
5216
","
5217
Returns the name of the default schema for this session.
Thomas Mueller's avatar
Thomas Mueller committed
5218 5219 5220 5221
","
CALL SCHEMA()
"

5222 5223 5224
"Functions (System)","SCOPE_IDENTITY","
SCOPE_IDENTITY()
","
5225
Returns the last inserted identity value for this session for the current scope
5226
(the current statement).
5227 5228 5229 5230 5231 5232
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
5233
"Functions (System)","SESSION_ID","
5234
SESSION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
5235
","
5236 5237 5238 5239
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
5240 5241 5242 5243 5244
","
CALL SESSION_ID()
"

"Functions (System)","SET","
5245
SET(@variableName, value)
Thomas Mueller's avatar
Thomas Mueller committed
5246
","
5247 5248 5249
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
5250
When used in a subquery, not all rows might be read depending on the query plan.
Thomas Mueller's avatar
Thomas Mueller committed
5251
This can be used to implement running totals / cumulative sums.
Thomas Mueller's avatar
Thomas Mueller committed
5252 5253 5254 5255 5256
","
SELECT X, SET(@I, IFNULL(@I, 0)+X) RUNNING_TOTAL FROM SYSTEM_RANGE(1, 10)
"

"Functions (System)","TABLE","
5257 5258
{ TABLE | TABLE_DISTINCT }
( { name dataType = array|rowValueExpression } [,...] )
Thomas Mueller's avatar
Thomas Mueller committed
5259 5260 5261
","
Returns the result set. TABLE_DISTINCT removes duplicate rows.
","
5262 5263
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
5264 5265 5266
"

"Functions (System)","TRANSACTION_ID","
5267
TRANSACTION_ID()
Thomas Mueller's avatar
Thomas Mueller committed
5268
","
5269 5270
Returns the current transaction id for this session.
This method returns NULL if there is no uncommitted change, or if the the database is not persisted.
Thomas Mueller's avatar
Thomas Mueller committed
5271
Otherwise a value of the following form is returned:
5272
""logFileId-position-sessionId"".
5273 5274
This method returns a string.
The value is unique across database restarts (values are not re-used).
Thomas Mueller's avatar
Thomas Mueller committed
5275 5276 5277 5278
","
CALL TRANSACTION_ID()
"

5279 5280 5281 5282 5283 5284 5285 5286 5287 5288 5289 5290
"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);
"

5291 5292 5293 5294 5295 5296 5297 5298 5299 5300 5301 5302
"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
5303
"Functions (System)","USER","
5304
{ USER | CURRENT_USER } ()
Thomas Mueller's avatar
Thomas Mueller committed
5305 5306 5307 5308 5309 5310
","
Returns the name of the current user of this session.
","
CURRENT_USER()
"

5311 5312 5313 5314 5315 5316 5317 5318
"Functions (System)","H2VERSION","
H2VERSION()
","
Returns the H2 version as a String.
","
H2VERSION()
"

5319
"Functions (Window)","ROW_NUMBER","
5320
ROW_NUMBER() OVER windowNameOrSpecification
5321 5322
","
Returns the number of the current row starting with 1.
5323
Window frame clause is not allowed for this function.
5324 5325 5326 5327 5328 5329 5330 5331 5332 5333

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","
5334
RANK() OVER windowNameOrSpecification
5335 5336 5337 5338 5339
","
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.
5340 5341
This function requires window order clause.
Window frame clause is not allowed for this function.
5342 5343 5344 5345 5346 5347 5348 5349 5350

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","
5351
DENSE_RANK() OVER windowNameOrSpecification
5352 5353 5354 5355 5356
","
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.
5357 5358
This function requires window order clause.
Window frame clause is not allowed for this function.
5359 5360 5361 5362

Window functions are currently experimental in H2 and should be used with caution.
They also may require a lot of memory for large queries.
","
5363 5364 5365 5366 5367
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","
5368
PERCENT_RANK() OVER windowNameOrSpecification
5369 5370 5371 5372
","
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.
5373
Note that result is always 0 if window order clause is not specified.
5374
Window frame clause is not allowed for this function.
5375 5376 5377 5378 5379 5380 5381 5382 5383

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","
5384
CUME_DIST() OVER windowNameOrSpecification
5385 5386 5387 5388 5389
","
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.
5390
Note that result is always 1 if window order clause is not specified.
5391
Window frame clause is not allowed for this function.
5392 5393 5394 5395 5396 5397

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

5400
"Functions (Window)","NTILE","
5401
NTILE(long) OVER windowNameOrSpecification
5402 5403
","
Distributes the rows into a specified number of groups.
5404
Number of groups should be a positive long value.
5405 5406 5407
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.
5408 5409
This function requires window order clause.
Window frame clause is not allowed for this function.
5410 5411 5412 5413 5414 5415 5416 5417

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

5418 5419
"Functions (Window)","LEAD","
LEAD(value [, offsetInt [, defaultValue]]) [{RESPECT|IGNORE} NULLS]
5420
OVER windowNameOrSpecification
5421 5422 5423 5424 5425 5426 5427
","
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.
5428 5429
This function requires window order clause.
Window frame clause is not allowed for this function.
5430 5431 5432 5433 5434 5435 5436 5437 5438 5439 5440 5441

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]
5442
OVER windowNameOrSpecification
5443 5444 5445 5446 5447 5448 5449
","
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.
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 5460 5461

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

5462
"Functions (Window)","FIRST_VALUE","
5463 5464
FIRST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
5465 5466 5467 5468 5469 5470 5471 5472 5473 5474 5475 5476
","
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","
5477 5478
LAST_VALUE(value) [{RESPECT|IGNORE} NULLS]
OVER windowNameOrSpecification
5479 5480 5481 5482
","
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.
5483 5484
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.
5485 5486 5487 5488 5489

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;
5490 5491 5492 5493
SELECT LAST_VALUE(X) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
    RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING
), * FROM TEST;
5494 5495 5496
"

"Functions (Window)","NTH_VALUE","
5497
NTH_VALUE(value, nInt) [FROM {FIRST|LAST}] [{RESPECT|IGNORE} NULLS]
5498
OVER windowNameOrSpecification
5499 5500 5501
","
Returns the value in a row with a specified relative number in a window.
Relative row number must be positive.
5502
If FROM LAST is specified rows a counted backwards from the last row.
5503 5504
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.
5505 5506
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.
5507 5508 5509 5510 5511

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;
5512 5513 5514 5515
SELECT NTH_VALUE(X) IGNORE NULLS OVER (
    PARTITION BY CATEGORY ORDER BY ID
    RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
), * FROM TEST;
5516 5517
"

Thomas Mueller's avatar
Thomas Mueller committed
5518 5519 5520 5521 5522 5523 5524 5525 5526 5527 5528 5529 5530 5531 5532
"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)
"